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
Anonymous
Not applicable

Advanced Editor - Date Table Dynamically Setting Start and End Dates based on fact table date field

This is what I have hard coded in Query Editor currently for my start and end dates, and I would like to base them off of fact table min and max dates.

 

StartDate = #date(2012, 1, 1),
EndDate = Date.From(DateTime.LocalNow()) ,

 

Thank you for your help

1 ACCEPTED SOLUTION

Power Query:

 

= #table(type table[Date = date],List.Zip({List.Dates(List.Min(Fact[Date]),1+Duration.Days(List.Max(Fact[Date]) - List.Min(Fact[Date])),#duration(1,0,0,0))}))
Specializing in Power Query Formula Language (M)

View solution in original post

4 REPLIES 4
blopez11
Resident Rockstar
Resident Rockstar

I create my date tables using DAX

In the modeling tab, select New Table, then enter the DAX similar to the below

 

DateTable =
ADDCOLUMNS (
CALENDAR (MINX('FactTable',[Transaction Date]), MAXX('FactTable',[Transaction Date])),
"Year", YEAR ( [Date] ),
"QuarterOfYear", FORMAT ( [Date], "Q" ),
"MonthOfYear", FORMAT ( [Date], "MM" ),
"DateInt", FORMAT ( [Date], "YYYYMMDD" ),
"MonthName", FORMAT ( [Date], "mmmm" ),
"MonthInCalendar", FORMAT ( [Date], "mmm YYYY" ),
"QuarterInCalendar", "Q" & FORMAT ( [Date], "Q" ) & " " & FORMAT ( [Date], "YYYY" ),
"DayInWeek", WEEKDAY ( [Date] ),
"DayOfWeekName", FORMAT ( [Date], "dddd" ),
"DayOfWeekShort", FORMAT ( [Date], "ddd" ),
"YearMonthShort", FORMAT ( [Date], "YYYY/mmm" ),
"YearMonthSort", FORMAT ( [Date], "YYYYMM" ),
"Month", FORMAT ( [Date], "mmm" ))

Anonymous
Not applicable

When I have more time, I could work on converting the rest of my Date Fields to DAX so I could use your logic. It is more straight forward than using Power Query. Thanks. Date Table Fields.PNG

Power Query:

 

= #table(type table[Date = date],List.Zip({List.Dates(List.Min(Fact[Date]),1+Duration.Days(List.Max(Fact[Date]) - List.Min(Fact[Date])),#duration(1,0,0,0))}))
Specializing in Power Query Formula Language (M)
Anonymous
Not applicable

Thank You!

 

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.