Find everything you need to get certified on Fabric—skills challenges, live sessions, exam prep, role guidance, and more. Get started
Hi All,
Requirement1:
Source team is generating price files on daily basis to the shared path. My requirement is to get only last business day of each month file in to Power Query & other files to be excluded. If last working of month is holiday then before day file to be selected.
Below highlighted file only to be selected for month of March.
In below example last working day is holiday so prior date file to be selected.
Requirement2:
Also prices of current month should fetch from previous month file. Each file is storing data of forward prices.
Some one of you please help me with this requirement in Power Query.
Thanks in Advance.
Solved! Go to Solution.
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMjLXNzDSNzIwMlbSUYpUitUBCllgCBnqGxijKcIUscAUssQQMjbAFEI23Q9mnwmGfWgixqgisQA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Date = _t, Workday = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"Date", type date}, {"Workday", type text}}),
#"Last Workday of Last Month" = let rs = Table.ToRecords(#"Changed Type") in Table.AddColumn(#"Changed Type", "LWLM", (r) => List.Last(List.Select(rs, each Date.EndOfMonth([Date])=Date.StartOfMonth(r[Date])-#duration(1,0,0,0) and [Workday]="Y"))[Date]?)
in
#"Last Workday of Last Month"
A showcase of powerful Excel worksheet formulas,
=IFERROR(MAX(FILTER([Date];(EOMONTH([Date]+0;0)=EOMONTH([@Date];-1))*([Workday]="Y")));"")
Expertise = List.Accumulate( {Days as from Today}, {Skills and Knowledge}, (Current, Everyday) => Current & Day.LeanAndPractise(Everyday) ) |
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMjLXNzDSNzIwMlbSUYpUitUBCllgCBnqGxijKcIUscAUssQQMjbAFEI23Q9mnwmGfWgixqgisQA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Date = _t, Workday = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"Date", type date}, {"Workday", type text}}),
#"Last Workday of Last Month" = let rs = Table.ToRecords(#"Changed Type") in Table.AddColumn(#"Changed Type", "LWLM", (r) => List.Last(List.Select(rs, each Date.EndOfMonth([Date])=Date.StartOfMonth(r[Date])-#duration(1,0,0,0) and [Workday]="Y"))[Date]?)
in
#"Last Workday of Last Month"
A showcase of powerful Excel worksheet formulas,
=IFERROR(MAX(FILTER([Date];(EOMONTH([Date]+0;0)=EOMONTH([@Date];-1))*([Workday]="Y")));"")
Expertise = List.Accumulate( {Days as from Today}, {Skills and Knowledge}, (Current, Everyday) => Current & Day.LeanAndPractise(Everyday) ) |
@Kavyachaganti please Try to this Date.EndOfMonth([Datemodify]) in using custom column.
@Kavyachaganti If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.