一、用M语言构建日期表

将以下内容复制到PowerBI查询编辑,创建空查询并保存为CreateCalendar即可

  1. let
  2. CalendarType = type function (
  3. optional CalendarYearStart as (type number meta [
  4. Documentation.FieldCaption = "开始年份,日期表从开始年份1月1日起。",
  5. Documentation.FieldDescription = "日期表从开始年份1月1日起",
  6. Documentation.SampleValues = { Date.Year( DateTime.LocalNow( ) ) - 1 } // Previous Year
  7. ]),
  8. optional CalendarYearEnd as (type number meta [
  9. Documentation.FieldCaption = "结束年份,日期表至结束年份12月31日止。",
  10. Documentation.FieldDescription = "日期表至结束年份12月31日止",
  11. Documentation.SampleValues = { Date.Year( DateTime.LocalNow( ) ) } // Current Year
  12. ]),
  13. optional CalendarFirstDayOfWeek as (type text meta [
  14. Documentation.FieldCaption = "定义一周开始日,从 Monday,Tuesday,Wednesday,Thursday,Friday,Saturday,Sunday中选择一个,缺省默认为Monday。",
  15. Documentation.FieldDescription = "从 Monday,Tuesday,Wednesday,Thursday,Friday,Saturday,Sunday中选择一个,缺省默认为Monday。",
  16. Documentation.SampleValues = { "Monday" }
  17. ]),
  18. optional CalendarCulture as (type text meta [
  19. Documentation.FieldCaption = "指定日期表显示月以及星期几的名称是中文或英文,en 表示英文,zh 表示中文,缺省默认与系统一致。",
  20. Documentation.FieldDescription = " en 表示英文,zh 表示中文,缺省默认与系统一致。",
  21. Documentation.SampleValues = { "zh" }
  22. ])
  23. )
  24. as table meta [
  25. Documentation.Name = "构建日期表",
  26. Documentation.LongDescription = "创建指定年份之间的日期表。并可进行各种设置。",
  27. Documentation.Examples = {
  28. [
  29. Description = "返回当前年份日期表",
  30. Code = "CreateCalendar()",
  31. Result = "当前年份日期表。"
  32. ],
  33. [
  34. Description = "返回指定年份的日期表",
  35. Code = "CreateCalendar( 2017 )",
  36. Result = "返回2017/01/01至2017/12/31之间的日期表。"
  37. ],
  38. [
  39. Description = "返回起止年份之间的日期表",
  40. Code = "CreateCalendar( 2015 , 2017 )",
  41. Result = "返回2015/01/01至2017/12/31之间的日期表。"
  42. ],
  43. [
  44. Description = "返回起止年份之间的日期表,并指定周二为每周的第一天",
  45. Code = "CreateCalendar( 2015 , 2017 , ""Tuesday"" )",
  46. Result = "2015/01/01至2017/12/31之间的日期表,且周二是每周的第一天。"
  47. ],
  48. [
  49. Description = "返回起止年份之间的日期表,并指定周二为每周的第一天,并使用英文显示名称。",
  50. Code = "CreateCalendar( 2015 , 2017 , ""Tuesday"", ""en"" )",
  51. Result = "2015/01/01至2017/12/31之间的日期表,且周二是每周的第一天,并使用英文显示月名称及星期几的名称。"
  52. ]
  53. }
  54. ],
  55. CreateCalendar = ( optional CalendarYearStart as number, optional CalendarYearEnd as number, optional CalendarFirstDayOfWeek as text, optional CalendarCulture as text) => let
  56. begin_year = CalendarYearStart ,
  57. end_year = CalendarYearEnd ,
  58. first_day_of_week = if Text.Lower( CalendarFirstDayOfWeek ) = "monday" then Day.Monday
  59. else if Text.Lower( CalendarFirstDayOfWeek ) = "tuesday" then Day.Tuesday
  60. else if Text.Lower( CalendarFirstDayOfWeek ) = "wednesday" then Day.Wednesday
  61. else if Text.Lower( CalendarFirstDayOfWeek ) = "thursday" then Day.Thursday
  62. else if Text.Lower( CalendarFirstDayOfWeek ) = "friday" then Day.Friday
  63. else if Text.Lower( CalendarFirstDayOfWeek ) = "saturday" then Day.Saturday
  64. else if Text.Lower( CalendarFirstDayOfWeek ) = "sunday" then Day.Sunday
  65. else if CalendarFirstDayOfWeek <> null then error "参数错误:参数CalendarFirstDayOfWeek必须是Monday,Tuesday,Wednesday,Thursday,Friday,Saturday,Sunday中的一个。"
  66. else Day.Monday ,
  67. culture = if CalendarCulture <> null then CalendarCulture else "zh" , // "en" , "zh"
  68. y1 = if begin_year <> null then begin_year else if end_year <> null then end_year else Date.Year( DateTime.LocalNow() ) ,
  69. y2 = if end_year <> null then end_year else if begin_year <> null then begin_year else Date.Year( DateTime.LocalNow() ) ,
  70. calendar_list = { Number.From ( #date( Number.From( y1 ) , 1 , 1 ) ) .. Number.From( #date( Number.From( y2 ) , 12, 31 ) ) },
  71. calendar_list_table = Table.FromList(calendar_list, Splitter.SplitByNothing(), null, null, ExtraValues.Error),
  72. #"Changed Type" = Table.TransformColumnTypes(calendar_list_table,{{"Column1", type date}}),
  73. #"Renamed Columns" = Table.RenameColumns(#"Changed Type",{{"Column1", "Date"}}),
  74. #"Inserted Year" = Table.AddColumn(#"Renamed Columns", "Year", each Date.Year([Date]), Int64.Type),
  75. #"Inserted Quarter" = Table.AddColumn(#"Inserted Year", "Quarter", each Date.QuarterOfYear([Date]), Int64.Type),
  76. #"Inserted Month" = Table.AddColumn(#"Inserted Quarter", "Month", each Date.Month([Date]), Int64.Type),
  77. #"Inserted Week of Year" = Table.AddColumn(#"Inserted Month", "WeekOfYear", each Date.WeekOfYear( [Date] , first_day_of_week ), Int64.Type),
  78. #"Inserted Week of Month" = Table.AddColumn(#"Inserted Week of Year", "WeekOfMonth", each Date.WeekOfMonth( [Date] ), Int64.Type),
  79. #"Inserted Start of Week" = Table.AddColumn(#"Inserted Week of Month", "DateOfWeekStart", each Date.StartOfWeek( [Date] ), type date),
  80. #"Inserted End of Week" = Table.AddColumn(#"Inserted Start of Week", "DateOfWeekEnd", each Date.EndOfWeek([Date]), type date),
  81. #"Inserted Day" = Table.AddColumn(#"Inserted End of Week", "DayOfMonth", each Date.Day([Date]), Int64.Type),
  82. #"Inserted Day of Week" = Table.AddColumn(#"Inserted Day", "DayOfWeek", each Date.DayOfWeek( [Date] , first_day_of_week ), Int64.Type),
  83. #"Inserted Day of Year" = Table.AddColumn(#"Inserted Day of Week", "DayOfYear", each Date.DayOfYear([Date]), Int64.Type),
  84. #"Inserted Day Name" = Table.AddColumn(#"Inserted Day of Year", "DayOfWeekName", each Date.DayOfWeekName( [Date] , culture ), type text),
  85. #"Inserted Year Name" = Table.AddColumn(#"Inserted Day Name", "YearName", each "Y" & Text.From( [Year] ) , type text ),
  86. #"Inserted Quarter Name" = Table.AddColumn(#"Inserted Year Name", "QuarterName", each "Q" & Text.From( [Quarter] ) , type text ),
  87. #"Inserted Month Name" = Table.AddColumn(#"Inserted Quarter Name", "MonthName", each Date.MonthName( [Date] , culture ), type text),
  88. #"Inserted Week Name" = Table.AddColumn(#"Inserted Month Name", "WeekName", each "W" & Text.From( [WeekOfYear] ) , type text ),
  89. #"Inserted Year Quarter" = Table.AddColumn(#"Inserted Week Name", "YearQuarter", each [Year] * 100 + [Quarter] , Int64.Type ),
  90. #"Inserted Year Month" = Table.AddColumn(#"Inserted Year Quarter", "YearMonth", each [Year] * 100 + [Month] , Int64.Type ),
  91. #"Inserted Year Week" = Table.AddColumn(#"Inserted Year Month", "YearWeek", each [Year] * 100 + [WeekOfYear] , Int64.Type ),
  92. #"Inserted Date Code" = Table.AddColumn(#"Inserted Year Week", "DateCode", each [Year] * 10000 + [Month] * 100 + [DayOfMonth] , Int64.Type )
  93. in
  94. if culture = "zh"
  95. then Table.RenameColumns( #"Inserted Date Code" ,{{"Date", "日期"}, {"Year", "年"}, {"Quarter", "季"}, {"Month", "月"}, {"WeekOfYear", "周"}, {"WeekOfMonth", "月周"}, {"DayOfMonth", "月日"}, {"DateOfWeekStart", "周开始日期"}, {"DateOfWeekEnd", "周结束日期"}, {"DayOfWeek", "周天"}, {"DayOfYear", "年日"}, {"DayOfWeekName", "星期几名称"}, {"YearName", "年份名称"}, {"QuarterName", "季度名称"}, {"MonthName", "月份名称"}, {"WeekName", "周名称"}, {"YearQuarter", "年季"}, {"YearMonth", "年月"}, {"YearWeek", "年周"}, {"DateCode", "日期码"}})
  96. else #"Inserted Date Code"
  97. in
  98. Value.ReplaceType( CreateCalendar , CalendarType )

二、用DAX构建日期表

  1. Calendar =
  2. ------------------------------------------------------------------------
  3. VAR WeekNumberFlag = 2 // 1 - sunday , 2 - monday
  4. // 1 - Sunday (1) and ends on Saturday (7). numbered 1 through 7.
  5. // 2 - Monday (1) and ends on Sunday (7).
  6. // 3 - Monday (0) and ends on Sunday (6).numbered 1 through 7
  7. VAR WeekDayFlag = 2
  8. VAR CalendarYearStart = 2016
  9. VAR CalendarYearEnd = 2017
  10. -------------------------------------------------------------------------
  11. VAR CalendarBase = CALENDAR( DATE( CalendarYearStart , 1 , 1 ) , DATE( CalendarYearEnd , 12 , 31 ) )
  12. RETURN
  13. GENERATE (
  14. CalendarBase,
  15. VAR CalendarCurrentDate = [Date]
  16. VAR CalendarYear = YEAR ( CalendarCurrentDate )
  17. VAR CalendarMonth = MONTH ( CalendarCurrentDate )
  18. VAR CalendarQuarter = SWITCH( TRUE() ,
  19. CalendarMonth <= 3 , 1 ,
  20. CalendarMonth <= 6 , 2 ,
  21. CalendarMonth <= 9 , 3 ,
  22. 4
  23. )
  24. VAR CalendarYearMonth = CalendarYear * 100 + CalendarMonth
  25. VAR CalendarYearWeek = CalendarYear * 100 + WEEKNUM( CalendarCurrentDate )
  26. VAR CalendarDayOfWeek = WEEKDAY( CalendarCurrentDate , WeekDayFlag )
  27. VAR CalendarWeekOfYear = WEEKNUM( CalendarCurrentDate , WeekNumberFlag )
  28. VAR CalendarDayOfMonth = DAY( CalendarCurrentDate )
  29. RETURN ROW (
  30. "Year" , CalendarYear ,
  31. "Quarter" , CalendarQuarter ,
  32. "Month" , CalendarMonth ,
  33. "WeekOfYear" , CalendarWeekOfYear ,
  34. "DayOfMonth" , CalendarDayOfMonth ,
  35. "DayOfWeek" , CalendarDayOfWeek ,
  36. "DayOfWeekName" , FORMAT( CalendarCurrentDate , "aaaa" ) ,
  37. "YearName" , "Y" & CalendarYear ,
  38. "QuarterName" , "Q" & CalendarQuarter ,
  39. "MonthName", FORMAT ( CalendarCurrentDate, "mmm" ) ,
  40. "WeekName", "W" & CalendarWeekOfYear ,
  41. "YearQuarter", CalendarYear * 100 + CalendarQuarter ,
  42. "YearMonth" , CalendarYearMonth ,
  43. "YearWeek" , CalendarYear * 100 + CalendarWeekOfYear ,
  44. "DateCode" , CalendarYear * 10000 + CalendarMonth * 100 + CalendarDayOfMonth
  45. )
  46. )