cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
Highlighted
Frequent Visitor

Generate Unique ID in Power Query (M Code) or Power Power Pivot (DAX Code)

Hi Everyone,

 

Could anyone help me to write M or Dax Code to generate Unique ID as shown below

 

 

Old IDNew IDItemUnique ID
 1ATN13
12ATN23
23ATN33

 

Many thanks for your help.

 

Regards,

Heng

1 ACCEPTED SOLUTION

Accepted Solutions
Highlighted
Super User III
Super User III

Re: Generate Unique ID in Power Query (M Code) or Power Power Pivot (DAX Code)

Hey,

 

just adjust the measure New like so

 

New = 
var New = 
IF(HASONEVALUE('Table1'[Customer])
	,CALCULATE(
        FIRSTNONBLANK('Table1'[New ID], 1)
        ,ALLEXCEPT('Table1',Table1[Customer])
        ,'Table1'[Status] = "Active"
    )
	,BLANK()
)
return
IF(HASONEVALUE('Table1'[Customer])
	,IF(VALUES(Table1[New ID]) = New
		,New
		,BLANK()
	)
)

and the measure Revenue total like so

 

Revenue total = 
var New = 
IF(HASONEVALUE('Table1'[Customer])
	,CALCULATE(
        FIRSTNONBLANK('Table1'[New ID], 1)
        ,ALLEXCEPT('Table1',Table1[Customer])
        ,'Table1'[Status] = "Active"
    )
	,BLANK()
)
return
IF(HASONEVALUE('Table1'[Customer])
	,IF(VALUES(Table1[New ID]) = [New]
		,CALCULATE( 
			SUMX(VALUES('Table1'[Customer]),	
				CALCULATE(
					SUM(Table1[Revenue])
					,ALLEXCEPT('Table1',Table1[Customer])
				)
			)
		)
		,BLANK()
	)
	,CALCULATE( 
			SUMX(VALUES('Table1'[Customer]),	
				CALCULATE(
					SUM(Table1[Revenue])
					,ALLEXCEPT('Table1',Table1[Customer])
				)
			)
		)
)

Then the output will look like this

Contracts - result final.png

Regards

 



Did I answer your question? Mark my post as a solution, this will help others!

Proud to be a Super User!
I accept Kudos 😉
Hamburg, Germany

View solution in original post

8 REPLIES 8
Highlighted
Super User III
Super User III

Re: Generate Unique ID in Power Query (M Code) or Power Power Pivot (DAX Code)

Hey,

 

can you please describe the rule how the "Unique ID" has to be rerived, and also I do not understand what makes the ID unique if it repeats 3 times.

 

Regards 



Did I answer your question? Mark my post as a solution, this will help others!

Proud to be a Super User!
I accept Kudos 😉
Hamburg, Germany
Highlighted
Frequent Visitor

Re: Generate Unique ID in Power Query (M Code) or Power Power Pivot (DAX Code)

Hi TomMartens,

 

For example, customer buy house No1 but later they change to House No2 and later on they change to House No3 but the revenue already paid in house No1 and House No 2. Thus I want to sum all the revenue for House No3 which I need to have the same ID in order for me to sum up the revenue

 

Input:

 

Old IDNew IDCustomerItemStatusRevenueNew
 1CustomerAHouse No1Inactive50003
12CustomerAHouse No2Inactive100003
23CustomerAHouse No3Active200003

Output: M or Dax code to show this result

 

Old IDNew IDCustomerItemStatusRevenueNew
23CustomerAHouse No3Active350003

 

Many thanks for help

Highlighted
Super User III
Super User III

Re: Generate Unique ID in Power Query (M Code) or Power Power Pivot (DAX Code)

Hey,

 

so what you are saying is this:

  • the column "New" gets its value from the "latest" (maximum) value of column "New ID"
  • create a measure "overall revenues" and just display the value if the latest "New ID" is selected

Is my understaning of your requirement correct?

 

Regards



Did I answer your question? Mark my post as a solution, this will help others!

Proud to be a Super User!
I accept Kudos 😉
Hamburg, Germany
Highlighted
Frequent Visitor

Re: Generate Unique ID in Power Query (M Code) or Power Power Pivot (DAX Code)

Hi TomMartens,

 

Yes. but we need to know the related contract based on the new and the old ID.

 

I have many customers that change the house and this example I just showing 2 customers.

Thus, how to write the M or Dax code to generate column " New"

Input

Old IDNew IDCustomerItemStatusRevenueNew
 20CustomerAHouse No1Inactive500030
2025CustomerAHouse No2Inactive1000030
2530CustomerAHouse No3Active2000030
 60CustomerBHouse NoBInactive2000080
6065CustomerBHouse NoCInactive1000080
6580CustomerBHouse NoDActive3000080

 

Output:

Old IDNew IDCustomerItemStatusRevenueNew
 30CustomerAHouse No3Active3500030
6580CustomerBHouse NoDActive6000080

 

Sorry for any inconvenince cause for my bad writing

 

Many thanks,

 

Regards,

Heng

Highlighted
Super User III
Super User III

Re: Generate Unique ID in Power Query (M Code) or Power Power Pivot (DAX Code)

Hey,

 

here is a little Power BI file I created three measures (should work the same in Power Pivot)

This measure identifies the last New ID (the status is active)

 

New = 
IF(HASONEVALUE('Table1'[Customer])
	,CALCULATE(
        FIRSTNONBLANK('Table1'[New ID], 1)
        ,ALLEXCEPT('Table1',Table1[Customer])
        ,'Table1'[Status] = "Active"
    )
	,BLANK()
)

I created measures to determine the corresponding Old ID and New ID where the Status is active

 

 

Old ID calc = 
IF(HASONEVALUE(Table1[Customer]), 
	MAXX(VALUES('Table1'[Old ID]),
		IF(MAX('Table1'[New ID]) = [New]
			,CALCULATE(
				MAX('Table1'[Old ID])
				,ALLEXCEPT('Table1',Table1[Customer])
			)
		,BLANK()
		)
	),
BLANK()
)

and

 

 

New ID calc = 
IF(HASONEVALUE(Table1[Customer]), 
	MAXX(VALUES('Table1'[New ID]),
		IF(MAX('Table1'[New ID]) = [New]
			,CALCULATE(
				MAX('Table1'[New ID])
				,ALLEXCEPT('Table1',Table1[Customer])
			)
		,BLANK()
		)
	),
BLANK()
)

and finally a measure that adds up all the revenues from each customer

Revenue total = 
CALCULATE( 
	SUMX(VALUES('Table1'[Customer]),
		
			CALCULATE(
				SUM(Table1[Revenue])
				,ALLEXCEPT('Table1',Table1[Customer])
			
		)
	)
)

 

These measures create the following output

Contracts - result.png

 

Hope this is what you are looking for

 

Regards



Did I answer your question? Mark my post as a solution, this will help others!

Proud to be a Super User!
I accept Kudos 😉
Hamburg, Germany
Highlighted
Frequent Visitor

Re: Generate Unique ID in Power Query (M Code) or Power Power Pivot (DAX Code)

Hi TomMartens,

 

Thanks for your valuable time helping me.

 

Your measure is already working for customer but if I put the item it shows below result

 

 Contract.PNG

 

 

but if I want to show the same output as my previous email

 

Output:

Old IDNew IDCustomerItemStatusRevenueNew
 2530CustomerAHouse No3Active3500030
6580CustomerBHouse NoDActive6000080

Many thanks again

Regards,

Heng

 

 

Highlighted
Super User III
Super User III

Re: Generate Unique ID in Power Query (M Code) or Power Power Pivot (DAX Code)

Hey,

 

just adjust the measure New like so

 

New = 
var New = 
IF(HASONEVALUE('Table1'[Customer])
	,CALCULATE(
        FIRSTNONBLANK('Table1'[New ID], 1)
        ,ALLEXCEPT('Table1',Table1[Customer])
        ,'Table1'[Status] = "Active"
    )
	,BLANK()
)
return
IF(HASONEVALUE('Table1'[Customer])
	,IF(VALUES(Table1[New ID]) = New
		,New
		,BLANK()
	)
)

and the measure Revenue total like so

 

Revenue total = 
var New = 
IF(HASONEVALUE('Table1'[Customer])
	,CALCULATE(
        FIRSTNONBLANK('Table1'[New ID], 1)
        ,ALLEXCEPT('Table1',Table1[Customer])
        ,'Table1'[Status] = "Active"
    )
	,BLANK()
)
return
IF(HASONEVALUE('Table1'[Customer])
	,IF(VALUES(Table1[New ID]) = [New]
		,CALCULATE( 
			SUMX(VALUES('Table1'[Customer]),	
				CALCULATE(
					SUM(Table1[Revenue])
					,ALLEXCEPT('Table1',Table1[Customer])
				)
			)
		)
		,BLANK()
	)
	,CALCULATE( 
			SUMX(VALUES('Table1'[Customer]),	
				CALCULATE(
					SUM(Table1[Revenue])
					,ALLEXCEPT('Table1',Table1[Customer])
				)
			)
		)
)

Then the output will look like this

Contracts - result final.png

Regards

 



Did I answer your question? Mark my post as a solution, this will help others!

Proud to be a Super User!
I accept Kudos 😉
Hamburg, Germany

View solution in original post

Highlighted
Frequent Visitor

Re: Generate Unique ID in Power Query (M Code) or Power Power Pivot (DAX Code)

Hi Martens,

 

Now it is working. Thank you Smiley Happy

Have a nice day!

Regards,

 

Heng

Helpful resources

Announcements
June 2020 Community Highlights

June 2020 Community Highlights

Featured community members, changes to the Community, and more! Read up on recent Power BI community news.

Using the Community

Using the Community

Need help with the Power BI Community? Our 'Using the Community' support articles are a great place to start.

Community Summit North America

Community Summit North America

Innovate, Collaborate, Grow. The top training and networking event across the globe for Microsoft Business Applications

Power Platform 2020 release wave 2 plan

Power Platform 2020 release wave 2 plan

Features releasing from October 2020 through March 2021

Top Solution Authors
Top Kudoed Authors