Skip to main content
cancel
Showing results for 
Search instead for 
Did you mean: 

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
lavdeepk
Resolver I
Resolver I

How to identify new and Old Txn based on Previous year data ?

Hi

 

I need your help to create a calculated column.

 

Refer to the below sample data I have year-wise txn I want to categorize all txn based on condition. if any ref no exists in last year txn then mark it as "OLD"  Else "NEW"  in the  Status field . (refer to desired results )

 

Ref  No_FYStatus (desired results)
011872FY-20NEW
006104FY-20NEW
146318FY-20NEW
002702FY-20NEW
001449FY-21NEW
014478FY-21NEW
006104FY-21OLD
016876FY-21NEW
002702FY-21OLD
134890FY-21NEW
000143FY-21NEW
008019FY-21NEW
106009FY-22NEW
083291FY-22NEW
000143FY-22OLD
002906FY-22NEW
000292FY-22NEW
001449FY-22OLD
006817FY-22NEW
014478FY-22OLD

 

2 ACCEPTED SOLUTIONS
lbendlin
Super User
Super User

You didn't specify if you wanted a measure or a calculated column. Here is a calculated column.

 

Status = 
var r = 'Table'[Ref  No_]
var f = 'Table'[FY]
var c = CALCULATE(COUNTROWS('Table'),All('Table'),'Table'[Ref  No_]=r,'Table'[FY]<f)
return if(c=0,"New","Old")

View solution in original post

Ashish_Mathur
Super User
Super User

Hi,

This calculated column formula works

=if(CALCULATE(COUNTROWS(Data),FILTER(data,Data[Ref  No_]=EARLIER(Data[Ref  No_])&&Data[FY]<EARLIER(Data[FY])))=1,"Old","New")

Hope this helps.

Untitled.png


Regards,
Ashish Mathur
http://www.ashishmathur.com
https://www.linkedin.com/in/excelenthusiasts/

View solution in original post

5 REPLIES 5
Ashish_Mathur
Super User
Super User

Hi,

This calculated column formula works

=if(CALCULATE(COUNTROWS(Data),FILTER(data,Data[Ref  No_]=EARLIER(Data[Ref  No_])&&Data[FY]<EARLIER(Data[FY])))=1,"Old","New")

Hope this helps.

Untitled.png


Regards,
Ashish Mathur
http://www.ashishmathur.com
https://www.linkedin.com/in/excelenthusiasts/

What if there is more than one previous row?

Change =1 to >=1


Regards,
Ashish Mathur
http://www.ashishmathur.com
https://www.linkedin.com/in/excelenthusiasts/
FrankAT
Community Champion
Community Champion

Hi @lavdeepk ,

if you need a measure you can do it like this:

 

24-07-_2021_00-20-02.png

 

Status = 
VAR _Min =
    CALCULATE ( MIN ( 'Table'[FY] ), ALLEXCEPT ( 'Table', 'Table'[Ref  No_] ) )
RETURN
    IF ( MIN ( 'Table'[FY] ) = _Min, "New", "Old" )

With kind regards from the town where the legend of the 'Pied Piper of Hamelin' is at home
FrankAT (Proud to be a Datanaut)

lbendlin
Super User
Super User

You didn't specify if you wanted a measure or a calculated column. Here is a calculated column.

 

Status = 
var r = 'Table'[Ref  No_]
var f = 'Table'[FY]
var c = CALCULATE(COUNTROWS('Table'),All('Table'),'Table'[Ref  No_]=r,'Table'[FY]<f)
return if(c=0,"New","Old")

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

Check out the April 2024 Power BI update to learn about new features.

April Fabric Community Update

Fabric Community Update - April 2024

Find out what's new and trending in the Fabric Community.