Skip to main content
cancel
Showing results for 
Search instead for 
Did you mean: 

Earn the coveted Fabric Analytics Engineer certification. 100% off your exam for a limited time only!

Reply
likhithar
Helper III
Helper III

Create Date Table based on Max and Min Order Date from the fact Table

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.

1 ACCEPTED 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





Did I answer your question? Mark my post as a solution! Kudos are also appreciated!

To learn more about Power BI, follow me on Twitter or subscribe on YouTube.


@mahoneypa HoosierBI on YouTube


View solution in original post

5 REPLIES 5
Anonymous
Not applicable

HI @likhithar ,

 

Try this: 

Noorani_0-1643036629224.png

 

mahoneypat
Employee
Employee

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





Did I answer your question? Mark my post as a solution! Kudos are also appreciated!

To learn more about Power BI, follow me on Twitter or subscribe on YouTube.


@mahoneypa HoosierBI 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





Did I answer your question? Mark my post as a solution! Kudos are also appreciated!

To learn more about Power BI, follow me on Twitter or subscribe on YouTube.


@mahoneypa HoosierBI on YouTube


Helpful resources

Announcements
April AMA free

Microsoft Fabric AMA Livestream

Join us Tuesday, April 09, 9:00 – 10:00 AM PST for a live, expert-led Q&A session on all things Microsoft Fabric!

March Fabric Community Update

Fabric Community Update - March 2024

Find out what's new and trending in the Fabric Community.

Top Solution Authors
Top Kudoed Authors