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

Calling all Data Engineers! Fabric Data Engineer (Exam DP-700) live sessions are back! Starting October 16th. Sign up.

Reply
VijayAntonyM
Helper I
Helper I

DAX Measure: identify unique rows before sum is calculated

Hi Team,

Good day,

 

We wanted to SUM the volumn column but consider only unique records,

Highlighted expected column in YELLOW color , Would like to set 0 for duplicate records on based

datekey, payer,payer_parent,eng_code as below, Same time this should be work even for filters and slicers.

 

datekeypayerpayer_namepayer_parentpayer_parent_nameegn_codeegn_nameVolumeVolumeBusiness_UnitAttributeValue
3/1/2024013730L3HARRIS IMS-KEO0007366010L3HARRIS TECHNOLOGIES1042078000L3 TECHNOLOGIES2222Dom SPAir0
3/1/2024013730L3HARRIS IMS-KEO0007366010L3HARRIS TECHNOLOGIES1042078000L3 TECHNOLOGIES220Dom SPGround0.066276617
3/1/2024013730L3HARRIS IMS-KEO0007366010L3HARRIS TECHNOLOGIES1042078000L3 TECHNOLOGIES220Dom SPFacilities0.004344208
2/1/2024039927L-3 MARITIME SYSTEMS0007366010L3HARRIS TECHNOLOGIES1042078000L3 TECHNOLOGIES1010Dom SPAir0
2/1/2024039927L-3 MARITIME SYSTEMS0007366010L3HARRIS TECHNOLOGIES1042078000L3 TECHNOLOGIES100Dom SPGround0.036742053
2/1/2024039927L-3 MARITIME SYSTEMS0007366010L3HARRIS TECHNOLOGIES1042078000L3 TECHNOLOGIES100Dom SPFacilities0.00285356

 

 

Thanks

M. Vijay Antony

1 ACCEPTED SOLUTION
Anonymous
Not applicable

Hi @VijayAntonyM 

 

Thank you very much Rupak_bi for your prompt reply.

 

First, you can create a calculated column to combine datekey, payer, payer_parent, and egn_code to form a unique identifier.

 

UniqueID = [datekey] & "-" & [payer] & "-" & [payer_parent] & "-" & [egn_code]

 

Then create a measure.

AdjustedVolume = 
var _rank = 
RANKX(
    FILTER(
        ALL('Table'),
        'Table'[UniqueID] = MAX('Table'[UniqueID])
    ),
    CALCULATE(MAX('Table'[Attribute])),
    ,
    ASC,
    Dense
)
RETURN
IF(
    _rank = 1,
    SUM('Table'[Volume]),
    0
)

 

If you don't want to create calculated columns, try that too:

 

Measure AdjustedVolume = 
var _rank = 
RANKX(
    FILTER(
        ALL('Table'),
        'Table'[datekey] = MAX('Table'[datekey])
        &&
        'Table'[payer] = MAX('Table'[payer])
        &&
        'Table'[payer_parent] = MAX('Table'[payer_parent])
        &&
        'Table'[egn_code] = MAX('Table'[egn_code])
    ),
    CALCULATE(MAX('Table'[Attribute])),
    ,
    ASC,
    Dense
)
RETURN
IF(
    _rank = 1,
    SUM('Table'[Volume]),
    0
)

 

Here is the result.

 

vnuocmsft_0-1732522103703.png

 

Regards,

Nono Chen

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

2 REPLIES 2
Rupak_bi
Super User
Super User

Hi @VijayAntonyM ,

 

Please see below image. Hope this solves your problem using a simgle measure. I dont think making duplicate entries Zero is really required as far as your output is concerned.

Rupak_bi_0-1732354697775.png

 



Regards
Rupak
FOLLOW ME : https://www.linkedin.com/in/rupaksar/
Anonymous
Not applicable

Hi @VijayAntonyM 

 

Thank you very much Rupak_bi for your prompt reply.

 

First, you can create a calculated column to combine datekey, payer, payer_parent, and egn_code to form a unique identifier.

 

UniqueID = [datekey] & "-" & [payer] & "-" & [payer_parent] & "-" & [egn_code]

 

Then create a measure.

AdjustedVolume = 
var _rank = 
RANKX(
    FILTER(
        ALL('Table'),
        'Table'[UniqueID] = MAX('Table'[UniqueID])
    ),
    CALCULATE(MAX('Table'[Attribute])),
    ,
    ASC,
    Dense
)
RETURN
IF(
    _rank = 1,
    SUM('Table'[Volume]),
    0
)

 

If you don't want to create calculated columns, try that too:

 

Measure AdjustedVolume = 
var _rank = 
RANKX(
    FILTER(
        ALL('Table'),
        'Table'[datekey] = MAX('Table'[datekey])
        &&
        'Table'[payer] = MAX('Table'[payer])
        &&
        'Table'[payer_parent] = MAX('Table'[payer_parent])
        &&
        'Table'[egn_code] = MAX('Table'[egn_code])
    ),
    CALCULATE(MAX('Table'[Attribute])),
    ,
    ASC,
    Dense
)
RETURN
IF(
    _rank = 1,
    SUM('Table'[Volume]),
    0
)

 

Here is the result.

 

vnuocmsft_0-1732522103703.png

 

Regards,

Nono Chen

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

Helpful resources

Announcements
November Fabric Update Carousel

Fabric Monthly Update - November 2025

Check out the November 2025 Fabric update to learn about new features.

Fabric Data Days Carousel

Fabric Data Days

Advance your Data & AI career with 50 days of live learning, contests, hands-on challenges, study groups & certifications and more!

FabCon Atlanta 2026 carousel

FabCon Atlanta 2026

Join us at FabCon Atlanta, March 16-20, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.

Users online (27)