March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Early bird discount ends December 31.
Register NowBe one of the first to start using Fabric Databases. View on-demand sessions with database experts and the Microsoft product team to learn just how easy it is to get started. Watch now
Hello everyone.
I have written the measure shown below. I get the following duplicated Rank values. What I would like to do is concatenate the CIS Type Description value when a Rank is duplicated. I have tried a few measures that don't seem to work. Is there anyone who might be able to point me in the right direction? Thanks.
CIS - Rank CIS Types Current Month =
VAR _Calc=
RANKX(
ALL( 'Lookup: CI Types'[CIS Type ID] ),
SUMX(
FILTER(
ALL('Lookup: CI Types'[CIS Type Description]),
NOT('Lookup: CI Types'[CIS Type Description] ) in { "Criteria One", "Criteria Two" }
),
[CIS - Intake Count by CI Type-Subtype Current Month]
),
, DESC, Skip
)
RETURN
_Calc
Solved! Go to Solution.
Hi @plantew1
Can you try the below?
CIS - Rank CIS Types with Concatenation =
VAR _Ranking =
SUMMARIZE(
ALL ( 'Lookup: CI Types' ) ,
'Lookup: CI Types'[CIS Type ID] ,
"Rank" , RANKX (
ALL ( 'Lookup: CI Types'[CIS Type ID] ) ,
SUMX (
FILTER (
ALL ( 'Lookup: CI Types'[CIS Type Description] ) ,
NOT ( 'Lookup: CI Types'[CIS Type Description] ) IN { "Criteria One", "Criteria Two" }
) ,
[CIS - Intake Count by CI Type-Subtype Current Month]
) ,
, DESC , Skip
) ,
"TypeDesc" , 'Lookup: CI Types'[CIS Type Description]
)
VAR _ConcatenateTypes =
CALCULATE (
CONCATENATEX (
FILTER (
_Ranking ,
[Rank] = EARLIER ( [Rank] )
) ,
[TypeDesc] , ", " ) ,
REMOVEFILTERS ( 'Lookup: CI Types'[CIS Type ID] )
)
RETURN
IF (
COUNTROWS (
FILTER (
_Ranking ,
[Rank] = EARLIER ( [Rank] )
)
) > 1 ,
_ConcatenateTypes ,
MAX ( 'Lookup: CI Types'[CIS Type Description] )
)
Hope this works... let me know how it goes.
Theo
If I have posted a response that resolves your question, please accept it as a solution to formally close the post.
Also, if you are as passionate about Power BI, DAX and data as I am, please feel free to reach out if you have any questions, queries, or if you simply want to connect and talk to another data geek!
Want to connect?www.linkedin.com/in/theoconias
@plantew1 that's great to hear that it worked mate! Well done!
If I have posted a response that resolves your question, please accept it as a solution to formally close the post.
Also, if you are as passionate about Power BI, DAX and data as I am, please feel free to reach out if you have any questions, queries, or if you simply want to connect and talk to another data geek!
Want to connect?www.linkedin.com/in/theoconias
Hi @plantew1
Can you try the below?
CIS - Rank CIS Types with Concatenation =
VAR _Ranking =
SUMMARIZE(
ALL ( 'Lookup: CI Types' ) ,
'Lookup: CI Types'[CIS Type ID] ,
"Rank" , RANKX (
ALL ( 'Lookup: CI Types'[CIS Type ID] ) ,
SUMX (
FILTER (
ALL ( 'Lookup: CI Types'[CIS Type Description] ) ,
NOT ( 'Lookup: CI Types'[CIS Type Description] ) IN { "Criteria One", "Criteria Two" }
) ,
[CIS - Intake Count by CI Type-Subtype Current Month]
) ,
, DESC , Skip
) ,
"TypeDesc" , 'Lookup: CI Types'[CIS Type Description]
)
VAR _ConcatenateTypes =
CALCULATE (
CONCATENATEX (
FILTER (
_Ranking ,
[Rank] = EARLIER ( [Rank] )
) ,
[TypeDesc] , ", " ) ,
REMOVEFILTERS ( 'Lookup: CI Types'[CIS Type ID] )
)
RETURN
IF (
COUNTROWS (
FILTER (
_Ranking ,
[Rank] = EARLIER ( [Rank] )
)
) > 1 ,
_ConcatenateTypes ,
MAX ( 'Lookup: CI Types'[CIS Type Description] )
)
Hope this works... let me know how it goes.
Theo
If I have posted a response that resolves your question, please accept it as a solution to formally close the post.
Also, if you are as passionate about Power BI, DAX and data as I am, please feel free to reach out if you have any questions, queries, or if you simply want to connect and talk to another data geek!
Want to connect?www.linkedin.com/in/theoconias
Hi TheoC,
First, just wanted to thank you for taking the time to code this for me. I'm truely greatful.
I think you have managed to come extremely close.
The DAX intellisense was giving me issues (an error) on this line and the only way to get it to cooperate was to switch the CI Type Description field for the CI Type ID field. Unfortunately, this concatenates the ID field instead of the description field. I've tried hard to understand your method and am stuck to figure out how to modify it so that it's concatenating the descriptions instead of the IDs but doesn't produce an error on this line. I'm still learning, I'm afraid.
) , "TypeDesc" , 'Lookup: CI Types'[CIS Type Description] )
Actually, TheoC, I just figured it out. I needed to wrap the description field in MAX and now it works perfectly. Thank you so much for your time and for your help in finding a soluation.
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!
Your insights matter. That’s why we created a quick survey to learn about your experience finding answers to technical questions.
Arun Ulag shares exciting details about the Microsoft Fabric Conference 2025, which will be held in Las Vegas, NV.
User | Count |
---|---|
134 | |
91 | |
90 | |
64 | |
58 |
User | Count |
---|---|
201 | |
137 | |
107 | |
72 | |
68 |