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

Get Fabric Certified for FREE during Fabric Data Days. Don't miss your chance! Request now

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
Fabric Data Days Carousel

Fabric Data Days

Advance your Data & AI career with 50 days of live learning, contests, hands-on challenges, study groups & certifications and more!

October Power BI Update Carousel

Power BI Monthly Update - October 2025

Check out the October 2025 Power BI update to learn about new features.

FabCon Atlanta 2026 carousel

FabCon Atlanta 2026

Join us at FabCon Atlanta, March 16-20, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.

Top Solution Authors