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

Find everything you need to get certified on Fabric—skills challenges, live sessions, exam prep, role guidance, and more. Get started

Reply
Anonymous
Not applicable

Expand payment info in several rows

Hi,

 

I need a data model just like this:

Table 1

ClientIDStartEndDurationMonthsMonthly $Total $
5000118/12/201818/11/201911$529.183$5.821.012
5000728/06/201817/12/20186$144.303$865.819
5001528/06/201817/12/20186$296.516$1.779.095
5001807/12/201807/01/20191$30.000$30.000
5002428/03/201817/12/20189$108.755$978.794
5002907/12/201807/01/20191$100.000$100.000
5003318/12/201818/11/201911$74.020$814.217
5006907/12/201807/01/20191$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

ClientIDStartEnd#Payment ReceivedDurationMonthsMonthly $Total $
5000118/12/201818/11/2019118/12/201811$529.183$5.821.012
5000118/12/201818/11/2019218/01/201911$529.183$5.821.012
5000118/12/201818/11/2019318/02/201911$529.183$5.821.012
5000118/12/201818/11/2019418/03/201911$529.183$5.821.012
5000118/12/201818/11/2019518/04/201911$529.183$5.821.012
5000118/12/201818/11/2019618/05/201911$529.183$5.821.012
5000118/12/201818/11/2019718/06/201911$529.183$5.821.012
5000118/12/201818/11/2019818/07/201911$529.183$5.821.012
5000118/12/201818/11/2019918/08/201911$529.183$5.821.012
5000118/12/201818/11/20191018/09/201911$529.183$5.821.012
5000118/12/201818/11/20191118/10/201911$529.183$5.821.012
5000728/06/201817/12/2018128/06/20186$144.303$865.819
5000728/06/201817/12/2018228/07/20186$144.303$865.819
5000728/06/201817/12/2018328/08/20186$144.303$865.819
5000728/06/201817/12/2018428/09/20186$144.303$865.819
5000728/06/201817/12/2018528/10/20186$144.303$865.819
5000728/06/201817/12/2018628/11/20186$144.303$865.819

 

How can I do that directly in Power BI?

 

Thanks!

1 ACCEPTED SOLUTION
mahoneypat
Microsoft Employee
Microsoft Employee

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





Did I answer your question? Mark my post as a solution! Kudos are also appreciated!

To learn more about Power BI, follow me on Twitter or subscribe on YouTube.


@mahoneypa HoosierBI on YouTube


View solution in original post

2 REPLIES 2
mahoneypat
Microsoft Employee
Microsoft Employee

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





Did I answer your question? Mark my post as a solution! Kudos are also appreciated!

To learn more about Power BI, follow me on Twitter or subscribe on YouTube.


@mahoneypa HoosierBI on YouTube


Anonymous
Not applicable

@mahoneypat , this is exactly what I need! Thank you!

Helpful resources

Announcements
Sept PBI Carousel

Power BI Monthly Update - September 2024

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

September Hackathon Carousel

Microsoft Fabric & AI Learning Hackathon

Learn from experts, get hands-on experience, and win awesome prizes.

Sept NL Carousel

Fabric Community Update - September 2024

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

Top Solution Authors
Top Kudoed Authors