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
I am looking for a way to count the total numnber of duplicate records on a column. Using the sample data below for duplicate "Number", the expected output would be 6 = 4 for 001 + 2 for 003.
Solved! Go to Solution.
Try this formula:
Number of Duplicates =
var summaryTable = ADDCOLUMNS(VALUES('Table'[Column1]), "duplicates", CALCULATE(COUNT('Table'[Column1])))
return SUMX(FILTER(summaryTable, [duplicates] > 1), [duplicates])
If you want everything in one single measure, you can do as
Count Dups only Measure = SUMX( Filter( GROUPBY('Table', [Number], "Dups Cnt", COUNTX( CURRENTGROUP(), 1)), [Dups Cnt] > 1), [Dups Cnt])
You get the same output. I prefer two measure approach, as we can use "Cnts" for other places if needed.
🙂
Try this formula:
Number of Duplicates =
var summaryTable = ADDCOLUMNS(VALUES('Table'[Column1]), "duplicates", CALCULATE(COUNT('Table'[Column1])))
return SUMX(FILTER(summaryTable, [duplicates] > 1), [duplicates])
@vicky_ Do you know how I can adjust this so that it returns "0" instead of "Blank" if the result is no duplicates?
Use COALESCE ...
Say, like this
Count Dups only Measure 3 = COALESCE( SUMX( Filter( GROUPBY('Table', [Number], "Dups Cnt", COUNTX( CURRENTGROUP(), 1)), [Dups Cnt] > 1), [Dups Cnt]) , 0)
Worked perfectly. Thanks!
First of all your expected output is wrong! It should be 7
You can achieve this as two measure approach as below. hope it helps!
First measure to count
Cnts = count('Table'[Number])
Second measure to count duplicates
Count Dups only Measure = SUMX( FILTER ( DISTINCT ( 'Table'[Number] ), [Cnts] > 1 ), [Cnts] )
Sample output:
You're absolutely right. It should be 7. 🙄
Thanks!
If you want everything in one single measure, you can do as
Count Dups only Measure = SUMX( Filter( GROUPBY('Table', [Number], "Dups Cnt", COUNTX( CURRENTGROUP(), 1)), [Dups Cnt] > 1), [Dups Cnt])
You get the same output. I prefer two measure approach, as we can use "Cnts" for other places if needed.
🙂
Makes sense. Thanks!
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 |
---|---|
129 | |
90 | |
75 | |
58 | |
53 |
User | Count |
---|---|
200 | |
104 | |
101 | |
67 | |
55 |