The ultimate Microsoft Fabric, Power BI, Azure AI, and SQL learning event: Join us in Stockholm, September 24-27, 2024.
Save €200 with code MSCUST on top of early bird pricing!
Find everything you need to get certified on Fabric—skills challenges, live sessions, exam prep, role guidance, and more. Get started
Hi,
Can someone explain to me what this formula does -
Solved! Go to Solution.
Hi @Rdarshana ,
I created a sample pbix file(see the attachment), you can find the details in it. And for below formula, it will return the count of ID in the table 'Fact 1' which ID also in the dimenison table 'Dim 2'. However, it will also include the IDs in 'Fact 1' table which not exist in the table 'Dim 2' as blank values. All these blank values count as 1. Please check the below screenshot:
ID Count = COUNTROWS(DISTINCT(SELECTCOLUMNS('Fact 1', "ID Column", RELATED('Dim 2 '[ID Column]))))
So you can update the forumula as below to get the correct count of ids.
ID Count_new =
COUNTROWS (
FILTER (
DISTINCT (
SELECTCOLUMNS ( 'Fact 1', "ID Column", RELATED ( 'Dim 2'[Dim ID] ) )
),
[ID Column] <> BLANK ()
)
)
Best Regards
Hi @Rdarshana ,
I created a sample pbix file(see the attachment), you can find the details in it. And for below formula, it will return the count of ID in the table 'Fact 1' which ID also in the dimenison table 'Dim 2'. However, it will also include the IDs in 'Fact 1' table which not exist in the table 'Dim 2' as blank values. All these blank values count as 1. Please check the below screenshot:
ID Count = COUNTROWS(DISTINCT(SELECTCOLUMNS('Fact 1', "ID Column", RELATED('Dim 2 '[ID Column]))))
So you can update the forumula as below to get the correct count of ids.
ID Count_new =
COUNTROWS (
FILTER (
DISTINCT (
SELECTCOLUMNS ( 'Fact 1', "ID Column", RELATED ( 'Dim 2'[Dim ID] ) )
),
[ID Column] <> BLANK ()
)
)
Best Regards
This was indeed very helpful.
Thanks Matt.
The Dim ID in this screenshot above is not the primary key, but another attribute (ID).
I will need to test the other calcs to see if that works.
if it's not the primary key, just insert the VALUES function inside the countrows function
COUNTROWS(VALUES(table[column]))
That's what it looks like to me, but it also looks overly complex. Assuming Dim ID in dim 2 is the primary key, this should work.
ID Count = calculate(countrows('Dim 2 '),'Fact 1')
Or this next version is a bit easier to understand
Calculate(countrows('Dim 2'),crossfilter(fact1[key],DIM2[key],BOTH))
They both do the same thing; force the fact table to filter the Dim table based on the existence of matching data in the fact table.
Join the community in Stockholm for expert Microsoft Fabric learning including a very exciting keynote from Arun Ulag, Corporate Vice President, Azure Data.
Check out the August 2024 Power BI update to learn about new features.
User | Count |
---|---|
111 | |
79 | |
71 | |
48 | |
41 |
User | Count |
---|---|
138 | |
108 | |
71 | |
64 | |
58 |