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

Join us for an expert-led overview of the tools and concepts you'll need to become a Certified Power BI Data Analyst and pass exam PL-300. Register now.

Reply
PB10
Frequent Visitor

creating of measure to do column comparison and creating a new column with indicators

Hi all,
Your help will be good
I am trying to compare data of two weeks week 39,and week 40 , and am trying to do this:
- do a comparison to see which items occured in week 39 and also week 40, and give it a status "carryover " in a a status collumn
- items that occur in week 39 and not in week 40 give it a status "closed"
- Items that occur in week 40 and not in week 39 give it a status  "New"

Table2

categoryweek #Status
a39 
b39 
d39 
a40 
b40 
d40 
E40 


"I am a screen reader"

3 ACCEPTED SOLUTIONS

Hi,
Thank you for sharing your problem. I am assuming you want to do it with dax rather than in power query.
Create a calculated column and write this dax.

Column =
VAR Week39Count =
    CALCULATE(
        COUNTROWS('Table'),
        'Table'[week #] = 39,
        ALLEXCEPT('Table', 'Table'[category])
    )
VAR Week40Count =
    CALCULATE(
        COUNTROWS('Table'),
        'Table'[week #] = 40,
        ALLEXCEPT('Table', 'Table'[category])
    )
RETURN
    IF(Week39Count > 0 && Week40Count > 0, "carryover",
        IF(Week39Count > 0 && Week40Count = 0, "closed",
            IF(Week39Count = 0 && Week40Count > 0, "New", BLANK())
        )
    )
Muhammad_Ahmed_0-1728417771016.png

 



View solution in original post

Omid_Motamedise
Super User
Super User

use the next code

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WSlTSUTK2VIrViVZKQjBTEEyQAhMDuAIoMwXBdIUyYwE=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [category = _t, #"week #" = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"category", type text}, {"week #", Int64.Type}}),
    #"Added Custom" = Table.AddColumn(#"Changed Type", "Status", each [a=Table.SelectRows(Source, (x)=> x[category]=[category])[#"week #"], b= if a={"39"} then "New" else if a={"40"} then "closed" else "carryover "][b])
in
    #"Added Custom"

 

result in 

Omid_Motamedise_0-1728430052868.png

 

 

If my answer helped solve your issue, please consider marking it as the accepted solution. It helps others in the community find answers faster—and keeps the community growing stronger!
You can also check out my YouTube channel for tutorials, tips, and real-world solutions in Power Query with the following link
https://youtube.com/@omidbi?si=96Bo-ZsSwOx0Z36h

View solution in original post

Anonymous
Not applicable

Hi @PB10 ,
You can also try this dax

Status = 
VAR Week39 = CALCULATETABLE(VALUES('Table'[category]), 'Table'[week #] = 39)
VAR Week40 = CALCULATETABLE(VALUES('Table'[category]), 'Table'[week #] = 40)
RETURN
SWITCH(
    TRUE(),
    SELECTEDVALUE('Table'[category]) IN Week39 && SELECTEDVALUE('Table'[category]) IN Week40, "carryover",
    SELECTEDVALUE('Table'[category]) IN Week39 && NOT SELECTEDVALUE('Table'[category]) IN Week40, "closed",
    SELECTEDVALUE('Table'[category]) IN Week40 && NOT SELECTEDVALUE('Table'[category]) IN Week39, "New",
    BLANK()
)

It outputs exactly what you described.

Best regards,
Albert He


If this post helps, then please consider Accept it as the solution to help the other members find it more quickly

 

View solution in original post

6 REPLIES 6
Anonymous
Not applicable

Hi @PB10 ,
You can also try this dax

Status = 
VAR Week39 = CALCULATETABLE(VALUES('Table'[category]), 'Table'[week #] = 39)
VAR Week40 = CALCULATETABLE(VALUES('Table'[category]), 'Table'[week #] = 40)
RETURN
SWITCH(
    TRUE(),
    SELECTEDVALUE('Table'[category]) IN Week39 && SELECTEDVALUE('Table'[category]) IN Week40, "carryover",
    SELECTEDVALUE('Table'[category]) IN Week39 && NOT SELECTEDVALUE('Table'[category]) IN Week40, "closed",
    SELECTEDVALUE('Table'[category]) IN Week40 && NOT SELECTEDVALUE('Table'[category]) IN Week39, "New",
    BLANK()
)

It outputs exactly what you described.

Best regards,
Albert He


If this post helps, then please consider Accept it as the solution to help the other members find it more quickly

 

Omid_Motamedise
Super User
Super User

use the next code

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WSlTSUTK2VIrViVZKQjBTEEyQAhMDuAIoMwXBdIUyYwE=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [category = _t, #"week #" = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"category", type text}, {"week #", Int64.Type}}),
    #"Added Custom" = Table.AddColumn(#"Changed Type", "Status", each [a=Table.SelectRows(Source, (x)=> x[category]=[category])[#"week #"], b= if a={"39"} then "New" else if a={"40"} then "closed" else "carryover "][b])
in
    #"Added Custom"

 

result in 

Omid_Motamedise_0-1728430052868.png

 

 

If my answer helped solve your issue, please consider marking it as the accepted solution. It helps others in the community find answers faster—and keeps the community growing stronger!
You can also check out my YouTube channel for tutorials, tips, and real-world solutions in Power Query with the following link
https://youtube.com/@omidbi?si=96Bo-ZsSwOx0Z36h

Hi,
Thank you for sharing your problem. I am assuming you want to do it with dax rather than in power query.
Create a calculated column and write this dax.

Column =
VAR Week39Count =
    CALCULATE(
        COUNTROWS('Table'),
        'Table'[week #] = 39,
        ALLEXCEPT('Table', 'Table'[category])
    )
VAR Week40Count =
    CALCULATE(
        COUNTROWS('Table'),
        'Table'[week #] = 40,
        ALLEXCEPT('Table', 'Table'[category])
    )
RETURN
    IF(Week39Count > 0 && Week40Count > 0, "carryover",
        IF(Week39Count > 0 && Week40Count = 0, "closed",
            IF(Week39Count = 0 && Week40Count > 0, "New", BLANK())
        )
    )
Muhammad_Ahmed_0-1728417771016.png

 



PB10
Frequent Visitor

Thanks,  I have tried reading on this before but, explanation is  with image tables.
I am vision impaired and use a screen reader, so explanations with images not super helpfull

Apologies. 

 

INTERSECT allows you to find commonalities between two sets of data that have the same columns. It will return the rows that match between the two data sets. That would be your "carryover".

 

EXCEPT can work either way, identifying the items that are no longer there ( "churn" ) when comparing previous to recent data sets, or the items that are "new"  when comparing recent to previous data sets.

 

Your sample data does not include churn items.

lbendlin
Super User
Super User

Please read about EXCEPT() and INTERSECT().  There is also a pattern article you can follow. https://www.daxpatterns.com/new-and-returning-customers/

 

 

Helpful resources

Announcements
Join our Fabric User Panel

Join our Fabric User Panel

This is your chance to engage directly with the engineering team behind Fabric and Power BI. Share your experiences and shape the future.

June 2025 Power BI Update Carousel

Power BI Monthly Update - June 2025

Check out the June 2025 Power BI update to learn about new features.

June 2025 community update carousel

Fabric Community Update - June 2025

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