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

Get Fabric Certified for FREE during Fabric Data Days. Don't miss your chance! Learn more

Reply
vicentetic
Frequent Visitor

Filter two columns with names and surnames in a unique column without repeating

I have a problem with this transformation apparently easy. It's a list of inventors of patents. Some patents have two inventors. Some inventors appear in several patents. I've split them into two columns but now, I can not achieve a unique column with all de names (and surnames) but without repetitions.

In the end, I want a ranking of inventors

 

Thank you in advance

1 ACCEPTED SOLUTION

Hi @vicentetic ,

 

 

You will need to unpivot the column 

 

Here is one way to do it in the query editor.  To see how it works, just create a blank query, go to Advanced Editor, and replace the text there with the M code below. 

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMlTSUfLKz8gDUsGlxYl5SrE60UpGQF5AaklqEUgyMTe1GCxqDOT5JhZVwnSAxEyAHMe8PLh6kJgpkm6EmWYglUV5+TkpKMLmcJ6OkltRaopSbCwA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"patent ID" = _t, #"inventor 1" = _t, #"inventor 2" = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"patent ID", Int64.Type}, {"inventor 1", type text}, {"inventor 2", type text}}),
    #"Unpivoted Other Columns" = Table.UnpivotOtherColumns(#"Changed Type", {"patent ID"}, "Attribute", "Value"),
    #"Renamed Columns" = Table.RenameColumns(#"Unpivoted Other Columns",{{"Value", "Name"}, {"Attribute", "Inventor No"}})
in
    #"Renamed Columns"

 

 

Else go to Query Editor. Select the First Column abd the Click on UnPivot Columns, Unpivot Other Columns

 

1.jpg

 

 

 

 

2.JPG

 

 

Then use this measure

 

 

Count of Patents = Count ( 'Table'[patent ID])

 

3.JPG

 

 


Regards,

Harsh Nathani


Appreciate with a Kudos!! (Click the Thumbs Up Button)

Did I answer your question? Mark my post as a solution!

 

 

 

 

View solution in original post

6 REPLIES 6
Anonymous
Not applicable

Hi @vicentetic ,

Could you please provide some sample data and your expected results in the form of table in order to provide you a proper solution? Please also provide the calculation logic of Rank the inventors. Thank you.

Best Regards

Rena

Of course. I have prepared a simplified example of my problem

 

I HAVE THIS                                                     

patent IDinventor 1inventor 2
1JohnSusan
2PeterJames
3MaryJohn
4AnnPeter
5PeterSusan
6ArnoldSusan
7SusanFred

 

    

I WANT THIS

 

 INVENTORSNº Patents
 Susan4
 Peter3
 John2
 Mary1
 Ann1
 Arnold1
 Fred1
 James1

 

Thank you

Hi @vicentetic ,

 

 

You will need to unpivot the column 

 

Here is one way to do it in the query editor.  To see how it works, just create a blank query, go to Advanced Editor, and replace the text there with the M code below. 

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMlTSUfLKz8gDUsGlxYl5SrE60UpGQF5AaklqEUgyMTe1GCxqDOT5JhZVwnSAxEyAHMe8PLh6kJgpkm6EmWYglUV5+TkpKMLmcJ6OkltRaopSbCwA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"patent ID" = _t, #"inventor 1" = _t, #"inventor 2" = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"patent ID", Int64.Type}, {"inventor 1", type text}, {"inventor 2", type text}}),
    #"Unpivoted Other Columns" = Table.UnpivotOtherColumns(#"Changed Type", {"patent ID"}, "Attribute", "Value"),
    #"Renamed Columns" = Table.RenameColumns(#"Unpivoted Other Columns",{{"Value", "Name"}, {"Attribute", "Inventor No"}})
in
    #"Renamed Columns"

 

 

Else go to Query Editor. Select the First Column abd the Click on UnPivot Columns, Unpivot Other Columns

 

1.jpg

 

 

 

 

2.JPG

 

 

Then use this measure

 

 

Count of Patents = Count ( 'Table'[patent ID])

 

3.JPG

 

 


Regards,

Harsh Nathani


Appreciate with a Kudos!! (Click the Thumbs Up Button)

Did I answer your question? Mark my post as a solution!

 

 

 

 

Hi @vicentetic ,

 

You can do something as shown below:

 

Raw data is as follows:

Pragati11_0-1594803637432.png

 

I created a UNION on both columns in the raw data as follows using DAX: (creating a new table using following DAX)

Inventory Union = UNION(ADDCOLUMNS(Inventor, "Inventor", Inventor[Inventor1]), ADDCOLUMNS(Inventor, "2nd", Inventor[Inventor2]))
 
The table after union I get is as follows:
 
 
 

t1.png

 

The INVENTOR column in the above table has got all the inventor clubbing INVENTOR1 and INVENTOR2.

Now create a new table visual as follows:

Move INVENTOR column from union table.

Move COUNT(ID) column from union table.

t2.png

 

This gives you the desired output. Hope this helps.

 

Thanks,

Pragati

 
 
 

Best Regards,

Pragati Jain


MVP logo


LinkedIn | Twitter | Blog YouTube 

Did I answer your question? Mark my post as a solution! This will help others on the forum!

Appreciate your Kudos!!

Proud to be a Super User!!

Pragati11
Super User
Super User

HI @vicentetic ,

 

Can you share some sample data please?

Try if this helps:

 

UniqueCnt =  var uniqueTable = UNION(SELECTCOLUMNS('Tablename', "Inventor", [Inventor columnname]), SELECTCOLUMNS('Tablename', "Patent", [Patent columnname])) RETURN COUNTROWS(DISTINCT(uniqueTable))

 

Thanks,

Pragati

Best Regards,

Pragati Jain


MVP logo


LinkedIn | Twitter | Blog YouTube 

Did I answer your question? Mark my post as a solution! This will help others on the forum!

Appreciate your Kudos!!

Proud to be a Super User!!

Greg_Deckler
Community Champion
Community Champion

@vicentetic - Can you create a unique column by concatenating your two columns into a single new column? It would help if you could demonstrate what your data looks like. Please see this post regarding How to Get Your Question Answered Quickly: https://community.powerbi.com/t5/Community-Blog/How-to-Get-Your-Question-Answered-Quickly/ba-p/38490

The most important parts are:
1. Sample data as text, use the table tool in the editing bar
2. Expected output from sample data
3. Explanation in words of how to get from 1. to 2.



Follow on LinkedIn
@ me in replies or I'll lose your thread!!!
Instead of a Kudo, please vote for this idea
Become an expert!: Enterprise DNA
External Tools: MSHGQM
YouTube Channel!: Microsoft Hates Greg
Latest book!:
DAX For Humans

DAX is easy, CALCULATE makes DAX hard...

Helpful resources

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

October Power BI Update Carousel

Power BI Monthly Update - October 2025

Check out the October 2025 Power BI update to learn about new features.

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.

Top Solution Authors