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
RolandsP
Resolver IV
Resolver IV

Generate a list in Power Query for each index value

Hi,

I have a simple table in Power Query.

It contains following columns:

- index (unique key for each table entry)

- revenue

- forecastIntervalMonths

- forecastStartDate

- forecastEndDate

 

From this, I need to generate a list of a forecasted revenue stream for each "index" value that starts at "forecastStartDate" and ends at or before "forecastEndDate". Revenue stream recurs at each interval "forecastIntervalMonths" which is given in number> of months. For example, if it is 3, it means that revenue repeats every three months. Revenue should equal "revenue" amount at each interval. Results should be included in one table.

I would highly appreciate if someone could share an idea how this could be accomplished.

Thanks,

Rolands

1 ACCEPTED SOLUTION

That would be something like this:

 

let
    Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"index", Int64.Type}, {"revenue", Int64.Type}, {"forecastIntervalMonths", Int64.Type}, {"forecastStartDate", type date}, {"forecastEndDate", type date}}),
    AddedMonths = Table.AddColumn(#"Changed Type", "Months", each 12 * (Date.Year([forecastEndDate])-Date.Year([forecastStartDate])) + Date.Month([forecastEndDate]) - Date.Month([forecastStartDate]) - (if Date.Day([forecastStartDate]) > Date.Day([forecastEndDate]) then 1 else 0), Int64.Type),
    AddedDateList = Table.AddColumn(AddedMonths, "Dates", (ThisRow) => List.Transform({0..Number.IntegerDivide(ThisRow[Months],ThisRow[forecastIntervalMonths])}, each Date.AddMonths(ThisRow[forecastStartDate],_ * ThisRow[forecastIntervalMonths])), type {date}),
    RemovedMonths = Table.RemoveColumns(AddedDateList,{"Months"})
in
    RemovedMonths
Specializing in Power Query Formula Language (M)

View solution in original post

4 REPLIES 4
MarcelBeug
Community Champion
Community Champion

Maybe a question with a representative example would be a better idea than posting your question twice.

Specializing in Power Query Formula Language (M)

Here is how the data looks in a table:Power Query.PNG

 

 

 

 

 

I would like to have that new column is added which includes date list for each index value. For Index 1, it would include following dates (at 1-month interval) - 30/12/2017, 30/01/2018, 28/02/2018, 30/03/2018, ... 30/12/2019. 

Thanks!

That would be something like this:

 

let
    Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"index", Int64.Type}, {"revenue", Int64.Type}, {"forecastIntervalMonths", Int64.Type}, {"forecastStartDate", type date}, {"forecastEndDate", type date}}),
    AddedMonths = Table.AddColumn(#"Changed Type", "Months", each 12 * (Date.Year([forecastEndDate])-Date.Year([forecastStartDate])) + Date.Month([forecastEndDate]) - Date.Month([forecastStartDate]) - (if Date.Day([forecastStartDate]) > Date.Day([forecastEndDate]) then 1 else 0), Int64.Type),
    AddedDateList = Table.AddColumn(AddedMonths, "Dates", (ThisRow) => List.Transform({0..Number.IntegerDivide(ThisRow[Months],ThisRow[forecastIntervalMonths])}, each Date.AddMonths(ThisRow[forecastStartDate],_ * ThisRow[forecastIntervalMonths])), type {date}),
    RemovedMonths = Table.RemoveColumns(AddedDateList,{"Months"})
in
    RemovedMonths
Specializing in Power Query Formula Language (M)

This works exactly as I need. 

Thanks a lot!

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.