Oct 01 2021 05:36 AM
I successfully transformed my data in Power Query and in the steps to get the data almost to where I need it.
I'd like to take step 1a, step 2, and step 3 and put it into a final output in step 4.
Step1: How to do MONTH(TODAY()) and MONTH(TODAY())-1 in PQ?
Step 2 & 3: How to repeat the result in step 1b to duplicate rows?
Step 4: How to combine step 1a, step 2, and step 3 into one table?
Oct 01 2021 06:06 AM - edited Oct 01 2021 06:41 AM
Hello @Jpalaci1 !
Step 1 :
Step 2 & 3 :
In order to append step 1a, step 2 and step 3 into one table, you can simply use Table.Combine (more info here : Table.Combine - PowerQuery M | Microsoft Docs)
Step4 = Table.Combine({"Step1", "Step2", "Step3")}
Hope it will help,
Nicolas
Oct 01 2021 02:55 PM
Practically the same as @NicolasTld explained, in terms of generated scripts
Data
let
thisMonth = Date.StartOfMonth( Date.From( DateTime.LocalNow() ) ),
Source = Excel.CurrentWorkbook(){[Name="Data"]}[Content],
dataMonth = Table.AddColumn(Source, "dataMonth", each #date([Year], [Month], 1)),
Filter1 = Table.AddColumn(dataMonth, "Filter1", each [dataMonth] < thisMonth),
Filter2 = Table.AddColumn(Filter1, "Filter2", each [dataMonth] = thisMonth)
in
Filter2
Previous:
let
Source = Data,
#"Filtered Rows" = Table.SelectRows(Source, each ([Filter1] = true)),
RemoveFilters = Table.RemoveColumns(#"Filtered Rows",{"dataMonth", "Filter1", "Filter2"})
in
RemoveFilters
Current:
let
Source = Data,
FilterCurrent = Table.SelectRows(Source, each ([Filter2] = true)),
RemoveFilters = Table.RemoveColumns(FilterCurrent,{ "dataMonth", "Filter1", "Filter2"})
in
RemoveFilters
Future:
let
thisMonth = Date.StartOfMonth( Date.From( DateTime.LocalNow() ) ),
thisMonthNumber = Date.Month( thisMonth ),
otherMonths = {thisMonthNumber+1 .. 12},
Source = Data,
FilterCurrent = Table.SelectRows(Source, each ([Filter2] = true)),
RemoveFilters = Table.RemoveColumns(FilterCurrent,{"Month", "dataMonth", "Filter1", "Filter2"}),
AddMonths = Table.AddColumn(RemoveFilters, "Month", each otherMonths),
Duplicate = Table.ExpandListColumn(AddMonths, "Month")
in
Duplicate
fullYear:
let
Source = Table.Combine({Previous, Current, Future})
in
Source
Oct 01 2021 02:58 PM
SolutionOops, forgot to check if we are in December duplication is not required. As variant you may add if ... then ... else.
Oct 06 2021 02:42 AM
Oct 06 2021 02:43 AM
Oct 06 2021 02:46 AM
Oct 06 2021 04:21 AM
@Jpalaci1 , you are welcome