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

Be 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

Reply
ERing
Helper V
Helper V

"Total" Count of Duplicates

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.

 

 Capture_2.PNG

2 ACCEPTED SOLUTIONS
vicky_
Super User
Super User

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__0-1694731889457.png

 

View solution in original post

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.

 

🙂

View solution in original post

8 REPLIES 8
vicky_
Super User
Super User

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__0-1694731889457.png

 

@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!

sevenhills
Super User
Super User

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:

sevenhills_0-1694730816343.png

 

sevenhills_1-1694730846435.png

 

 

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!

Helpful resources

Announcements
Las Vegas 2025

Join us at the Microsoft Fabric Community Conference

March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!

Dec Fabric Community Survey

We want your feedback!

Your insights matter. That’s why we created a quick survey to learn about your experience finding answers to technical questions.

ArunFabCon

Microsoft Fabric Community Conference 2025

Arun Ulag shares exciting details about the Microsoft Fabric Conference 2025, which will be held in Las Vegas, NV.

December 2024

A Year in Review - December 2024

Find out what content was popular in the Fabric community during 2024.