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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
mrothschild
Continued Contributor
Continued Contributor

Creating new table from existing data

I have a BI table with the following info:

 

Asset IDDuration (mos)Start dateEnd Date
A63/31/20199/30/2019
B126/30/20196/30/2020
C47/31/201911/30/2019

 

I'd like to create a related table that results in the following:

 

Asset IDDuration (mos)Start dateEnd DatePeriodMonth
A63/31/20199/30/201903/31/2019
A63/31/20199/30/201914/30/2019
A63/31/20199/30/201925/31/2019
A63/31/20199/30/201936/30/2019
A63/31/20199/30/201947/31/2019
A63/31/20199/30/201958/31/2019
A63/31/20199/30/201969/30/2019
B126/30/20196/30/202006/30/2019
B126/30/20196/30/202017/31/2019
B126/30/20196/30/202028/31/2019
B126/30/20196/30/202039/30/2019
B126/30/20196/30/2020410/31/2019
B126/30/20196/30/2020511/30/2019
B126/30/20196/30/2020612/31/2019
B126/30/20196/30/202071/31/2020
B126/30/20196/30/202082/29/2020
B126/30/20196/30/202093/31/2020
B126/30/20196/30/2020104/30/2020
B126/30/20196/30/2020115/31/2020
B126/30/20196/30/2020126/30/2020
C47/31/201911/30/201907/31/2019
C47/31/201911/30/201918/31/2019
C47/31/201911/30/201929/30/2019
C47/31/201911/30/2019310/31/2019
C47/31/201911/30/2019411/30/2019

 

1 ACCEPTED SOLUTION
PattemManohar
Community Champion
Community Champion

@mrothschild Please follow the below steps:

 

1. Create a New Table as below (This will generate the sequence numbers from 0 till the maximum number available on the Duration field in source table. In this case it is 12)

 

Test215Series = 
VAR _MaxVal = MAX(Test215MultiRowSplit[Duration])
RETURN GENERATESERIES(0,_MaxVal)

 

image.png

 

2a. Then Create a New Table as below (Which will give a cartesian product of source table and the series table that was created above)

 

Test215Out = CROSSJOIN(Test215MultiRowSplit,Test215Series)

2b. Now, will remove the unnecessary records that are not required by flagging. Note I've renamed the Value field to Period field as requied. Add a new column as below

 

RemoveFlag = IF(Test215Out[Period]<=Test215Out[Duration],"Y","N")

2c. Filter only RemoveFlag = "Y" which are our expected records and then add a new column as below. 

 

Month = EDATE(Test215Out[StartDate],Test215Out[Period])

Final ResultFinal Result

 

 





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

Proud to be a PBI Community Champion




View solution in original post

4 REPLIES 4
PattemManohar
Community Champion
Community Champion

@mrothschild Please follow the below steps:

 

1. Create a New Table as below (This will generate the sequence numbers from 0 till the maximum number available on the Duration field in source table. In this case it is 12)

 

Test215Series = 
VAR _MaxVal = MAX(Test215MultiRowSplit[Duration])
RETURN GENERATESERIES(0,_MaxVal)

 

image.png

 

2a. Then Create a New Table as below (Which will give a cartesian product of source table and the series table that was created above)

 

Test215Out = CROSSJOIN(Test215MultiRowSplit,Test215Series)

2b. Now, will remove the unnecessary records that are not required by flagging. Note I've renamed the Value field to Period field as requied. Add a new column as below

 

RemoveFlag = IF(Test215Out[Period]<=Test215Out[Duration],"Y","N")

2c. Filter only RemoveFlag = "Y" which are our expected records and then add a new column as below. 

 

Month = EDATE(Test215Out[StartDate],Test215Out[Period])

Final ResultFinal Result

 

 





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

Proud to be a PBI Community Champion




Anonymous
Not applicable

As with most things, there are generally more than one solution. I went the Power Query route:

Final Table:

Final Table.png

 

You can step through the applied steps, but a quick rundown:

  • Create a list for each Asset ID of all the dates between start and end
  • Expand that list, and transform all those dates into EndOfMonth
  • Select AssetID and the new date column and remove duplicates
  • Group the rows by Asset ID
  • Add a new column that will produce a new table, but witih an index ( called period )
  • Then just some cleaning up (setting data types and such)

 

PBIX file if you feel inclined:

https://1drv.ms/f/s!Amqd8ArUSwDSzzEI55iEKiX7TfEC

 

-Nick

Perfect, thank you.  One question on the filtering in the data, I appreciate the output display, but this is the first time I've seen it used in BI (I've only been programming for a few weeks, so not surprised I haven't seen it before).  Does filtering impact display only or does it actually prevent use of data that's filtered to not be visible?

 

@mrothschild  I've kept that filter to make the steps clear, but the data will be there behind the scenes. Once you reached this step, You can create another final output table with subset of data where RemoveFlag = Y. This final table can be used further in your visuals or further calculations.





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

Proud to be a PBI Community Champion




Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

Check out the April 2024 Power BI update to learn about new features.

April Fabric Community Update

Fabric Community Update - April 2024

Find out what's new and trending in the Fabric Community.