Here is another way to accomplish this in Power Query, if you wish to use those periods in a slicer.
Here is the M Code:
let
TodaysDate = Date.From(DateTimeZone.FixedUtcNow()),
Ranges = {
{"Today", TodaysDate, TodaysDate, 1},
{"Yesterday", Date.AddDays(TodaysDate,-1), Date.AddDays(TodaysDate,-1), 2},
{"Last 30 Days", Date.AddDays(TodaysDate,-30), TodaysDate, 3},
{"Last 60 Days", Date.AddDays(TodaysDate,-60), TodaysDate, 4},
{"Last 90 Days", Date.AddDays(TodaysDate,-90), TodaysDate, 5}
},
fxCreatePeriodTabe = ( PeriodName as text, StartDate as date, EndDate as date, SortOrder as number ) as table =>
let
DayCount = Duration.Days(EndDate-StartDate)+1,
DateList = List.Dates(StartDate,DayCount,#duration(1,0,0,0)),
AddPeriodName = List.Transform(DateList, each {PeriodName,_,SortOrder}),
CreateTable = #table( type table[Period=text, Date=date, Sort=number], AddPeriodName)
in
CreateTable,
GetTables = List.Transform(Ranges, each fxCreatePeriodTabe(_{0}, _{1}, _{2}, _{3})),
Output = Table.Combine(GetTables)
in
Output
I’ve also attached the PBIX
EDNA 30-60-90 Slicer.pbix (1.8 MB)
Thanks
Jarrett