The ultimate Fabric, Power BI, SQL, and AI community-led learning event. Save €200 with code FABCOMM.
Get registeredEnhance your career with this limited time 50% discount on Fabric and Power BI exams. Ends August 31st. Request your voucher.
I have a BI table with the following info:
Asset ID | Duration (mos) | Start date | End Date |
A | 6 | 3/31/2019 | 9/30/2019 |
B | 12 | 6/30/2019 | 6/30/2020 |
C | 4 | 7/31/2019 | 11/30/2019 |
I'd like to create a related table that results in the following:
Asset ID | Duration (mos) | Start date | End Date | Period | Month |
A | 6 | 3/31/2019 | 9/30/2019 | 0 | 3/31/2019 |
A | 6 | 3/31/2019 | 9/30/2019 | 1 | 4/30/2019 |
A | 6 | 3/31/2019 | 9/30/2019 | 2 | 5/31/2019 |
A | 6 | 3/31/2019 | 9/30/2019 | 3 | 6/30/2019 |
A | 6 | 3/31/2019 | 9/30/2019 | 4 | 7/31/2019 |
A | 6 | 3/31/2019 | 9/30/2019 | 5 | 8/31/2019 |
A | 6 | 3/31/2019 | 9/30/2019 | 6 | 9/30/2019 |
B | 12 | 6/30/2019 | 6/30/2020 | 0 | 6/30/2019 |
B | 12 | 6/30/2019 | 6/30/2020 | 1 | 7/31/2019 |
B | 12 | 6/30/2019 | 6/30/2020 | 2 | 8/31/2019 |
B | 12 | 6/30/2019 | 6/30/2020 | 3 | 9/30/2019 |
B | 12 | 6/30/2019 | 6/30/2020 | 4 | 10/31/2019 |
B | 12 | 6/30/2019 | 6/30/2020 | 5 | 11/30/2019 |
B | 12 | 6/30/2019 | 6/30/2020 | 6 | 12/31/2019 |
B | 12 | 6/30/2019 | 6/30/2020 | 7 | 1/31/2020 |
B | 12 | 6/30/2019 | 6/30/2020 | 8 | 2/29/2020 |
B | 12 | 6/30/2019 | 6/30/2020 | 9 | 3/31/2020 |
B | 12 | 6/30/2019 | 6/30/2020 | 10 | 4/30/2020 |
B | 12 | 6/30/2019 | 6/30/2020 | 11 | 5/31/2020 |
B | 12 | 6/30/2019 | 6/30/2020 | 12 | 6/30/2020 |
C | 4 | 7/31/2019 | 11/30/2019 | 0 | 7/31/2019 |
C | 4 | 7/31/2019 | 11/30/2019 | 1 | 8/31/2019 |
C | 4 | 7/31/2019 | 11/30/2019 | 2 | 9/30/2019 |
C | 4 | 7/31/2019 | 11/30/2019 | 3 | 10/31/2019 |
C | 4 | 7/31/2019 | 11/30/2019 | 4 | 11/30/2019 |
Solved! Go to Solution.
@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)
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 Result
Proud to be a PBI 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)
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 Result
Proud to be a PBI Community Champion
As with most things, there are generally more than one solution. I went the Power Query route:
Final Table:
You can step through the applied steps, but a quick rundown:
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.
Proud to be a PBI Community Champion