Created
March 21, 2014 00:40
-
-
Save philbritton/9677152 to your computer and use it in GitHub Desktop.
create a killer date table in power query for excel
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
let CreateDateTable = (StartDate as date, EndDate as date, optional Culture as nullable text) as table => | |
let | |
DayCount = Duration.Days(Duration.From(EndDate - StartDate)), | |
Source = List.Dates(StartDate,DayCount,#duration(1,0,0,0)), | |
TableFromList = Table.FromList(Source, Splitter.SplitByNothing()), | |
ChangedType = Table.TransformColumnTypes(TableFromList,{{"Column1", type date}}), | |
RenamedColumns = Table.RenameColumns(ChangedType,{{"Column1", "Date"}}), | |
InsertYear = Table.AddColumn(RenamedColumns, "Year", each Date.Year([Date])), | |
InsertQuarter = Table.AddColumn(InsertYear, "QuarterOfYear", each Date.QuarterOfYear([Date])), | |
InsertMonth = Table.AddColumn(InsertQuarter, "MonthOfYear", each Date.Month([Date])), | |
InsertDay = Table.AddColumn(InsertMonth, "DayOfMonth", each Date.Day([Date])), | |
InsertDayInt = Table.AddColumn(InsertDay, "DateInt", each [Year] * 10000 + [MonthOfYear] * 100 + [DayOfMonth]), | |
InsertMonthName = Table.AddColumn(InsertDayInt, "MonthName", each Date.ToText([Date], "MMMM", Culture), type text), | |
InsertCalendarMonth = Table.AddColumn(InsertMonthName, "MonthInCalendar", each (try(Text.Range([MonthName],0,3)) otherwise [MonthName]) & " " & Number.ToText([Year])), | |
InsertCalendarQtr = Table.AddColumn(InsertCalendarMonth, "QuarterInCalendar", each "Q" & Number.ToText([QuarterOfYear]) & " " & Number.ToText([Year])), | |
InsertDayWeek = Table.AddColumn(InsertCalendarQtr, "DayInWeek", each Date.DayOfWeek([Date])), | |
InsertDayName = Table.AddColumn(InsertDayWeek, "DayOfWeekName", each Date.ToText([Date], "dddd", Culture), type text), | |
InsertWeekEnding = Table.AddColumn(InsertDayName, "WeekEnding", each Date.EndOfWeek([Date]), type date) | |
in | |
InsertWeekEnding | |
in | |
CreateDateTable |
Looks like this will work for me. Thanks a million$$$
Sign up for free
to join this conversation on GitHub.
Already have an account?
Sign in to comment
Nice code!
I think it worth to be pushed here:
https://github.com/tycho01/pquery