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

Get certified in Microsoft Fabric—for free! For a limited time, get a free DP-600 exam voucher to use by the end of 2024. Register now

Reply
RichaBansal
New Member

the number of times unpivoting a row

Hi PBI Experts,

 

RichaBansal_0-1712061812129.png

 

Can we achieve this?

 

Many many thanks in advance.

2 ACCEPTED SOLUTIONS
Joe_Barry
Super User
Super User

Hi @RichaBansal 

 

With that exact data no, but if the Start and End Columns were formated as dates, then yes.

 

  • Add a custom column  to create month amount between dates

 

Date.Year([End])*12+Date.Month([End])-Date.Year([Start])*12-Date.Month([Start])​

 

  • Create a column to calculate Monthly Amount

 

[Amount]/ [Custom]​

 

  • Create another column called "Intervals" 

 

List.Numbers(1,[Custom])​

 

  • Then add another to create the months 

 

Date.StartOfMonth(
  Date.AddMonths(
    [Start],
    [Intervals] -1
  )
))​

 

This should help

Joe

 

If you found my answer helpful and it solved your issue, please accept as solution




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

Proud to be a Super User!





Learn about the Star Schema, it will solve many issues in Power BI!

Date tables help! Learn more



LinkedIn
Let's connect on LinkedIn


View solution in original post

I think I missed a step. You will need to expand the list to new rows before adding the last step




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

Proud to be a Super User!





Learn about the Star Schema, it will solve many issues in Power BI!

Date tables help! Learn more



LinkedIn
Let's connect on LinkedIn


View solution in original post

6 REPLIES 6
Joe_Barry
Super User
Super User

Hi @RichaBansal 

 

With that exact data no, but if the Start and End Columns were formated as dates, then yes.

 

  • Add a custom column  to create month amount between dates

 

Date.Year([End])*12+Date.Month([End])-Date.Year([Start])*12-Date.Month([Start])​

 

  • Create a column to calculate Monthly Amount

 

[Amount]/ [Custom]​

 

  • Create another column called "Intervals" 

 

List.Numbers(1,[Custom])​

 

  • Then add another to create the months 

 

Date.StartOfMonth(
  Date.AddMonths(
    [Start],
    [Intervals] -1
  )
))​

 

This should help

Joe

 

If you found my answer helpful and it solved your issue, please accept as solution




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

Proud to be a Super User!





Learn about the Star Schema, it will solve many issues in Power BI!

Date tables help! Learn more



LinkedIn
Let's connect on LinkedIn


Hi Joe,

 

The start and end are dates. I got the list of numbers, but the Last column shows error.

RichaBansal_1-1712131774661.png

 

 

I think I missed a step. You will need to expand the list to new rows before adding the last step




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

Proud to be a Super User!





Learn about the Star Schema, it will solve many issues in Power BI!

Date tables help! Learn more



LinkedIn
Let's connect on LinkedIn


Worked like a charm 🙂

Thank you Joe. Have a pleasant day.

This will work only in case when Start and End are defined as dates. @RichaBansal, let us know if input Start and End are dates or just text "Jan" and "April"


Note: Check this link to learn how to use my query.
Check this link if you don't know how to provide sample data.

@RichaBansal, in case you have input stored as text, try this:

 

Result:

dufoq3_1-1712067284989.png

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45W8krMU9JRciwoyswB0oYGIKAUGwsA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Start = _t, End = _t, Amount = _t]),
    Transformed = Table.TransformColumns(Source, {
        {"Start", each Date.Month(Date.FromText("2024" & Text.Start(_,3) & "01", [Format="yyyyMMMdd", Culture="en-US"])), Int64.Type},
        {"End", each Date.Month(Date.FromText("2024" & Text.Start(_,3) & "01", [Format="yyyyMMMdd", Culture="en-US"])), Int64.Type},
        {"Amount", Number.From, type number}
}),
    Ad_FinalTable = Table.AddColumn(Transformed, "FinalTable", each 
        [ a = [Amount] / ([End]-[Start]+1),
          b = List.Transform({[Start]..[End]}, (x)=> Date.ToText(#date(2024,x,1), "MMM", "en-US")),
          c = Table.FromColumns({ b, List.Repeat({a}, List.Count(b)) }, type table[Month=text, Amount=number])
        ][c], type table),
    FinalTable = Table.Combine(Ad_FinalTable[FinalTable])
in
    FinalTable

 


Note: Check this link to learn how to use my query.
Check this link if you don't know how to provide sample data.

Helpful resources

Announcements
November Carousel

Fabric Community Update - November 2024

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

Live Sessions with Fabric DB

Be one of the first to start using Fabric Databases

Starting December 3, join live sessions with database experts and the Fabric product team to learn just how easy it is to get started.

Las Vegas 2025

Join us at the Microsoft Fabric Community Conference

March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Early Bird pricing ends December 9th.

Nov PBI Update Carousel

Power BI Monthly Update - November 2024

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