Starting December 3, join live sessions with database experts and the Microsoft product team to learn just how easy it is to get started
Learn moreGet certified in Microsoft Fabric—for free! For a limited time, get a free DP-600 exam voucher to use by the end of 2024. Register now
Hello All,
I have a fact table called Sales. There is a column Order Date in Sales Table.
I want to create a Date Table in Power Query based on Min Order Date and Max Order Date from the Fact Table.
How to derive that??
Thanks in Advance.
Solved! Go to Solution.
On you fact table query, select your time period column and on the Transform tab choose Add Suffix under Format dropdown. Add the suffix of 01 and then convert that column to a Date type. After that, you can reference that column in the List.Min and List.Max steps of that query to get a Date table that dynamically expands as you add more data. If needed, you can wrap the List.Max with Date.EndOfMonth to get the end of the final month.
Pat
To learn more about Power BI, follow me on Twitter or subscribe on YouTube.
Here is an expression you can use (or just see the approach in the first 3 lines).
let
StartDate = List.Min(Sales[SaleDate]),
EndDate = List.Max(Sales[SaleDate]),
Source = List.Dates(StartDate,Duration.Days(EndDate - StartDate),#duration(1,0,0,0)),
#"Converted to Table" = Table.FromList(Source, Splitter.SplitByNothing(), null, null, ExtraValues.Error),
#"Renamed Columns" = Table.RenameColumns(#"Converted to Table",{{"Column1", "Date"}}),
#"Changed Type" = Table.TransformColumnTypes(#"Renamed Columns",{{"Date", type date}}),
#"Inserted Month Name" = Table.AddColumn(#"Changed Type", "Month Name", each Date.MonthName([Date]), type text),
#"Inserted Month" = Table.AddColumn(#"Inserted Month Name", "Month", each Date.Month([Date]), Int64.Type),
#"Inserted Year" = Table.AddColumn(#"Inserted Month", "Year", each Date.Year([Date]), Int64.Type),
#"Inserted Day of Week" = Table.AddColumn(#"Inserted Year", "Day of Week", each Date.DayOfWeek([Date]), Int64.Type),
#"Added Custom" = Table.AddColumn(#"Inserted Day of Week", "YearMonth", each Number.ToText([Year])&Text.Start([Month Name],3)),
#"Changed Type2" = Table.TransformColumnTypes(#"Added Custom",{{"YearMonth", type text}}),
#"Added Custom Column" = Table.AddColumn(#"Changed Type2", "YearMonthSort", each Text.Combine({Date.ToText([Date], "yyyy"), Date.ToText([Date], "MM")}), type text),
#"Inserted Week of Year" = Table.AddColumn(#"Added Custom Column", "Week of Year", each Date.WeekOfYear([Date]), Int64.Type),
#"Inserted Quarter" = Table.AddColumn(#"Inserted Week of Year", "Quarter", each Date.QuarterOfYear([Date]), Int64.Type)
in
#"Inserted Quarter"
Pat
To learn more about Power BI, follow me on Twitter or subscribe on YouTube.
Thanks for this, is very useful. Any advice on how to add Fiscal Year, Fiscal Quarter, Fiscal Month. For a fiscal year that beggins in October?
@mahoneypat In my fact table,my time period is in "YYYYMM(202109)" ,how to convert that format to date time and how in creating date Table w.r.to the solution which you shared
On you fact table query, select your time period column and on the Transform tab choose Add Suffix under Format dropdown. Add the suffix of 01 and then convert that column to a Date type. After that, you can reference that column in the List.Min and List.Max steps of that query to get a Date table that dynamically expands as you add more data. If needed, you can wrap the List.Max with Date.EndOfMonth to get the end of the final month.
Pat
To learn more about Power BI, follow me on Twitter or subscribe on YouTube.
Starting December 3, join live sessions with database experts and the Fabric product team to learn just how easy it is to get started.
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Early Bird pricing ends December 9th.
User | Count |
---|---|
25 | |
12 | |
11 | |
11 | |
8 |
User | Count |
---|---|
46 | |
28 | |
14 | |
13 | |
13 |