Check your eligibility for this 50% exam voucher offer and join us for free live learning sessions to get prepared for Exam DP-700.
Get StartedDon't miss out! 2025 Microsoft Fabric Community Conference, March 31 - April 2, Las Vegas, Nevada. Use code MSCUST for a $150 discount. Prices go up February 11th. Register now.
Hi,
I need a data model just like this:
Table 1
ClientID | Start | End | DurationMonths | Monthly $ | Total $ |
50001 | 18/12/2018 | 18/11/2019 | 11 | $529.183 | $5.821.012 |
50007 | 28/06/2018 | 17/12/2018 | 6 | $144.303 | $865.819 |
50015 | 28/06/2018 | 17/12/2018 | 6 | $296.516 | $1.779.095 |
50018 | 07/12/2018 | 07/01/2019 | 1 | $30.000 | $30.000 |
50024 | 28/03/2018 | 17/12/2018 | 9 | $108.755 | $978.794 |
50029 | 07/12/2018 | 07/01/2019 | 1 | $100.000 | $100.000 |
50033 | 18/12/2018 | 18/11/2019 | 11 | $74.020 | $814.217 |
50069 | 07/12/2018 | 07/01/2019 | 1 | $100.000 | $100.000 |
In the first row in the Table 1 (above) I have a contract with 11 duration months where I received $529.183 monthly. I need to expand that 11 payments for the next 11 months in a new table in Power BI. Something like this:
Table 2
ClientID | Start | End | # | Payment Received | DurationMonths | Monthly $ | Total $ |
50001 | 18/12/2018 | 18/11/2019 | 1 | 18/12/2018 | 11 | $529.183 | $5.821.012 |
50001 | 18/12/2018 | 18/11/2019 | 2 | 18/01/2019 | 11 | $529.183 | $5.821.012 |
50001 | 18/12/2018 | 18/11/2019 | 3 | 18/02/2019 | 11 | $529.183 | $5.821.012 |
50001 | 18/12/2018 | 18/11/2019 | 4 | 18/03/2019 | 11 | $529.183 | $5.821.012 |
50001 | 18/12/2018 | 18/11/2019 | 5 | 18/04/2019 | 11 | $529.183 | $5.821.012 |
50001 | 18/12/2018 | 18/11/2019 | 6 | 18/05/2019 | 11 | $529.183 | $5.821.012 |
50001 | 18/12/2018 | 18/11/2019 | 7 | 18/06/2019 | 11 | $529.183 | $5.821.012 |
50001 | 18/12/2018 | 18/11/2019 | 8 | 18/07/2019 | 11 | $529.183 | $5.821.012 |
50001 | 18/12/2018 | 18/11/2019 | 9 | 18/08/2019 | 11 | $529.183 | $5.821.012 |
50001 | 18/12/2018 | 18/11/2019 | 10 | 18/09/2019 | 11 | $529.183 | $5.821.012 |
50001 | 18/12/2018 | 18/11/2019 | 11 | 18/10/2019 | 11 | $529.183 | $5.821.012 |
50007 | 28/06/2018 | 17/12/2018 | 1 | 28/06/2018 | 6 | $144.303 | $865.819 |
50007 | 28/06/2018 | 17/12/2018 | 2 | 28/07/2018 | 6 | $144.303 | $865.819 |
50007 | 28/06/2018 | 17/12/2018 | 3 | 28/08/2018 | 6 | $144.303 | $865.819 |
50007 | 28/06/2018 | 17/12/2018 | 4 | 28/09/2018 | 6 | $144.303 | $865.819 |
50007 | 28/06/2018 | 17/12/2018 | 5 | 28/10/2018 | 6 | $144.303 | $865.819 |
50007 | 28/06/2018 | 17/12/2018 | 6 | 28/11/2018 | 6 | $144.303 | $865.819 |
How can I do that directly in Power BI?
Thanks!
Solved! Go to Solution.
Here is one way to do it. Please see M code below that transforms your example data into the desired result. 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("nZBLDsQgDEPvgrqsUid8kpyl6v2vUaCU6WKkjmZnA8+22PeQAXBYA9vGsgnYhuFmvJl2vWRxYotdkgkTWMKxXgFaj8U2lBmgj7TSIE6JIjpvpSbU6EFzfqfFC2W+gkjVCZ4n317hiVSDz/wGRVCd+VCDlTS649du74Uw0txGLq5Vepq0vzczZvUtBx3jD9+uiSCdNk4krDdd/uw+Tg==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [ClientID = _t, Start = _t, End = _t, DurationMonths = _t, #"Monthly $" = _t, #"Total $" = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"ClientID", Int64.Type}, {"Start", type text}, {"End", type text}, {"DurationMonths", Int64.Type}, {"Monthly $", Currency.Type}, {"Total $", type text}}),
#"Changed Type with Locale" = Table.TransformColumnTypes(#"Changed Type", {{"Start", type date}}, "en-150"),
#"Added Custom" = Table.AddColumn(#"Changed Type with Locale", "Payment Received", each let startdate = [Start] in List.Transform({1..[DurationMonths]}, each Date.AddMonths(startdate, _))),
#"Expanded DateList" = Table.ExpandListColumn(#"Added Custom", "Payment Received"),
#"Changed Type1" = Table.TransformColumnTypes(#"Expanded DateList",{{"Payment Received", type date}})
in
#"Changed Type1"
Note that I needed a Change Date with locale step since i am in a different locale as you. You probably won't need that step.
If this works for you, please mark it as the solution. Kudos are appreciated too. Please let me know if not.
Regards,
Pat
To learn more about Power BI, follow me on Twitter or subscribe on YouTube.
Here is one way to do it. Please see M code below that transforms your example data into the desired result. 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("nZBLDsQgDEPvgrqsUid8kpyl6v2vUaCU6WKkjmZnA8+22PeQAXBYA9vGsgnYhuFmvJl2vWRxYotdkgkTWMKxXgFaj8U2lBmgj7TSIE6JIjpvpSbU6EFzfqfFC2W+gkjVCZ4n317hiVSDz/wGRVCd+VCDlTS649du74Uw0txGLq5Vepq0vzczZvUtBx3jD9+uiSCdNk4krDdd/uw+Tg==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [ClientID = _t, Start = _t, End = _t, DurationMonths = _t, #"Monthly $" = _t, #"Total $" = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"ClientID", Int64.Type}, {"Start", type text}, {"End", type text}, {"DurationMonths", Int64.Type}, {"Monthly $", Currency.Type}, {"Total $", type text}}),
#"Changed Type with Locale" = Table.TransformColumnTypes(#"Changed Type", {{"Start", type date}}, "en-150"),
#"Added Custom" = Table.AddColumn(#"Changed Type with Locale", "Payment Received", each let startdate = [Start] in List.Transform({1..[DurationMonths]}, each Date.AddMonths(startdate, _))),
#"Expanded DateList" = Table.ExpandListColumn(#"Added Custom", "Payment Received"),
#"Changed Type1" = Table.TransformColumnTypes(#"Expanded DateList",{{"Payment Received", type date}})
in
#"Changed Type1"
Note that I needed a Change Date with locale step since i am in a different locale as you. You probably won't need that step.
If this works for you, please mark it as the solution. Kudos are appreciated too. Please let me know if not.
Regards,
Pat
To learn more about Power BI, follow me on Twitter or subscribe on YouTube.
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Prices go up Feb. 11th.
Check out the January 2025 Power BI update to learn about new features in Reporting, Modeling, and Data Connectivity.
User | Count |
---|---|
143 | |
74 | |
63 | |
51 | |
47 |
User | Count |
---|---|
211 | |
85 | |
64 | |
59 | |
56 |