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

Power BI is turning 10! Let’s celebrate together with dataviz contests, interactive sessions, and giveaways. Register now.

Reply
blai
Frequent Visitor

Column or measure Conditionals

Hi, I have a column with this conditions: 

 

ConditionalColumn=
VAR userID= [UserID]
VAR IDduplicated = CALCULATE(COUNTROWS(table), ALLEXCEPT(table, table[UserID])) > 1
VAR shopIDduplicated =
    IF(
        IDduplicated,
        CALCULATE(
            COUNTROWS(table),
            ALLEXCEPT(table, table[UserID]),
            table[shopID] = EARLIER(table[shopID])
        ) > 1,
        FALSE()
    )
RETURN
    IF(
        IDduplicated && shopIDduplicated,
        "Yes",
        "No"
    )
 
I would rather, if UserID is duplicated, for each duplicated UserID, take their shopID. If the shopID is duplicated, put "Yes"; otherwise, put "No". Below, I show you what this conditional column is doing and what i want:
 
Example: I have 3 duplicated UserIDs, but 2 of them have the same shopID. I want the conditional column to show "Yes", only for those 2 lines; for the oder UserID, it becames "No".
 
What's wrong is in lines where UserID is "22" (lines number 2-3-4). It has "Yes" for all 3, but first shopID isn't equal to others, so it should be "No", "Yes", "Yes".
 
Conditional//shopID//categoryID//userID//YearStart;MonthStart;DayStart//YearFinish;MonthFinish;DayFinish
Column
No1111112023November102023October9
Yes2222222023February282023January16
Yes3333222023October62023October1
Yes3333222023October162023October16
No4444332023June12023May23
Yes555544   2023November3
Yes5555442023January192023January10
Yes5556442023July282023February13
Yes7775442023November22023August14
Yes6669552023May312023April17
Yes6669552023July212023June1

 

 

 

PS: The next level would be: once you have those "Yes" values, filter them for the same UserID, shopID, and check if they have the same categoryID. If they do, this would be the real "Yes"; the others would be "No". In that case, taking the table example, for the UserId "44", the correct sequence would be: Yes-Yes-No-No.

 

PS2: The final level would involve, once you have level 2, comparing the start date with the end date for lines that meet the previous criteria. If datediff is <=5 days, it should be "Yes"; otherwise, "No". Next step would be to do the same for the end date, comparing it with other lines' start dates. Before this, thake the next line and do the same... However, it's more important to have levels 1 first and 2 correct, not this level.

 

Any help is appreciated. Thanks!

 

 

3 REPLIES 3
ERD
Community Champion
Community Champion

@blai , you can play with these calculated columns to achieve your goal. Since the end date is earlier then start date, I had to change their placement in DATEDIFF formula.

level0 = 
VAR userIDs = CALCULATE ( COUNT ( t[userID] ), ALLEXCEPT ( t, t[userID] ) )
RETURN
    IF ( userIDs > 1, "Yes", "No" )
level1 = 
VAR shopIDs = CALCULATE ( COUNT ( t[shopID] ), ALLEXCEPT ( t, t[userID], t[shopID] ) )
RETURN
    IF ( shopIDs > 1, "Yes", "No" )
level2 = 
VAR categoryIDs = CALCULATE ( COUNT ( t[categoryID] ), ALLEXCEPT ( t, t[userID], t[shopID], t[categoryID] ) )
RETURN
    IF ( categoryIDs > 1, "Yes", "No" )
level3 =
VAR categoryIDs =
    CALCULATE (
        COUNT ( t[categoryID] ),
        ALLEXCEPT ( t, t[userID], t[shopID], t[categoryID] )
    )
VAR dt_start =
    IF (
        NOT ISBLANK ( t[YearStart] ),
        DATEVALUE ( t[YearStart] & "/" & t[MonthStart] & "/" & t[DayStart] )
    )
VAR dt_end =
    IF (
        NOT ISBLANK ( t[YearFinish] ),
        DATEVALUE ( t[YearFinish] & "/" & t[MonthFinish] & "/" & t[DayFinish] )
    )
VAR diff = DATEDIFF ( dt_start, dt_end, DAY )
RETURN
    IF ( categoryIDs > 1 && diff <= 5, "Yes", "No" )

ERD_0-1699452338804.png

 

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

Check out my latest demo report in the data story gallery.

Stand with Ukraine!


Here are official ways you can support Ukraine financially (accounts with multiple currencies):
1) Support the Armed Forces of Ukraine: https://bank.gov.ua/ua/about/support-the-armed-forces
2) Come Back Alive foundation: https://www.comebackalive.in.ua/

Thank you!

ERD
Community Champion
Community Champion

Hi @blai , why your start dates are later then the end dates?

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

Check out my latest demo report in the data story gallery.

Stand with Ukraine!


Here are official ways you can support Ukraine financially (accounts with multiple currencies):
1) Support the Armed Forces of Ukraine: https://bank.gov.ua/ua/about/support-the-armed-forces
2) Come Back Alive foundation: https://www.comebackalive.in.ua/

Thank you!

blai
Frequent Visitor

Sorry, I turned the headings! 

Tanks for the response!

By the way 2 things:

1.  If level3 were correctly done, in the example table, all values should be "No". This is because there aren't any startDate or endDate from other lines wher the datediff is <=5 days. The code you provided compares a line's own startDate with its own endDate, but what I want is to compare startDates and endDates from different lines, always complying with the previous characteristics or at least with the same UserID.

 

2. The idea is to unify all levels, but if that's not posible, I would create 3 filters with all conditional columns and check all 3 "Yes". 

 

PS: small detail: the dates are date type, and startDate is taken from a related table. Additionally, shopID is a created column related from other table

 

PS2: I would be happy if i could filter same UserID and shopID, (level1). To copy that and change the code with categoryID to filter both columns.

To simplify things: Here are examples, but before I explain you in words.

 

Level1

Only "Yes" when the same shopID and UserID

ShopIDUserIDConditional
11

1

Yes

111Yes
221No
331No
222No
223No
334Yes
334Yes

 

Level2:

Only "Yes" when the same shopID, UserID, and categoryID.

shopIDCategoryIDUserIDConditional
111111Yes
111111Yes
111111Yes
112221No
221111No
111112No
221112Yes
221112Yes
334443No
553334No

 

Level3: date below dd-mm-yyyy

Compare the startDate and endDate for the same shopID, UserID, and categoryID with other lines. If the date difference is less than or equal to 5 days, set Conditional to "Yes."

shopIDCategoryIDUserIDstartDateEndDateConditional
11111108/11/202309/11/2023No
11111125/11/202325/12/2023Yes
11111128/12/202311/01/2023Yes
22111113/01/202314/01/2023No
33444208/11/202310/11/2023No
33444308/11/202310/11/2023Yes
33444315/09/202303/11/2023Yes
4444431/01/202320/01/2023Yes
44444322/01/202322/01/2023Yes

 

Thanks for the help, and if you have any more questions, I'm here to assist!

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.