PowerBI中构建相对日期的终极方法

在PowerBI中基于日期进行相对化的分析至少需要点击3次,甚至还要输入1次,如下:

这种交互体验不够简单,所以实现简单常用的相对日期如下:

相对日期

Power Query M 实现方法

let

CalendarPeriodRelativeType =  type function (
        
            optional TheDateRelative as (type date meta [
                Documentation.FieldCaption = "相对日期",
                Documentation.FieldDescription = "如果为空,默认为今日",
                Documentation.SampleValues = { Date.From( DateTime.LocalNow( ) ) } 
            ]),
            
            optional IncludingTheDateRelative as (type logical meta [
                Documentation.FieldCaption = "是否包括该日期",
                Documentation.FieldDescription = "如果为空,默认为包括",
                Documentation.SampleValues = { true } 
            ]),

            optional CalendarFirstDayOfWeek as (type text meta [
                Documentation.FieldCaption = "定义一周开始日,从 Monday,Tuesday,Wednesday,Thursday,Friday,Saturday,Sunday中选择一个,缺省默认为Monday。",
                Documentation.FieldDescription = "从 Monday,Tuesday,Wednesday,Thursday,Friday,Saturday,Sunday中选择一个,缺省默认为Monday。",
                Documentation.SampleValues = { "Monday" }
            ])
        )

        as table meta [
            Documentation.Name = "构建相对日期区间表",
            Documentation.LongDescription = "创建以指定日期为基准的相对日期区间。并可进行各种设置。",
            Documentation.Examples = {
            [
                Description = "返回以当前日期为基准的相对日期区间表",
                Code = "CreateCalendarPeriodRelative()",
                Result = "返回以当前日期为基准的相对日期区间表"
            ],
            [
                Description = "返回以某日期为基准的相对日期区间表",
                Code = "CreateCalendarPeriodRelative( #date(2017,2,1) )",
                Result = "返回以 2017/02/01 为基准的相对日期区间表。"
            ],
            [
                Description = "返回以某日期为基准的相对日期区间表",
                Code = "CreateCalendarPeriodRelative( #date(2017,2,1) , false )",
                Result = "返回以 2017/02/01 为基准的相对日期区间表,且日期区间不包括该日期。"
            ],
            [
                Description = "返回以某日期为基准的相对日期区间表",
                Code = "CreateCalendarPeriodRelative( #date(2017,2,1) , false , ""Tuesday"")",
                Result = "返回以 2017/02/01 为基准的相对日期区间表,且日期区间不包括该日期,且周二是每周的第一天。"
            ]
            }
        ],

    fCreateCalendarPeriodRelative = ( 
        optional TheDateRelative as date,
        optional IncludingTheDateRelative as logical,
        optional CalendarFirstDayOfWeek as text  ) =>
    
    let

        IncludingTheDate = if IncludingTheDateRelative is null then true else IncludingTheDateRelative,

        TheDate =   
            if TheDateRelative is null 
            then Date.AddDays( Date.From( DateTime.LocalNow() ) , if IncludingTheDate then 0 else -1 )
            else Date.AddDays( TheDateRelative , if IncludingTheDate then 0 else -1 ) ,

        YearStart = Date.Year( TheDate ) - 1 ,
        YearEnd = Date.Year( TheDate ) ,
        FirstDayOfWeek =    if Text.Lower( CalendarFirstDayOfWeek ) = "monday" then Day.Monday
                            else if Text.Lower( CalendarFirstDayOfWeek ) = "tuesday" then Day.Tuesday
                            else if Text.Lower( CalendarFirstDayOfWeek ) = "wednesday" then Day.Wednesday
                            else if Text.Lower( CalendarFirstDayOfWeek ) = "thursday" then Day.Thursday
                            else if Text.Lower( CalendarFirstDayOfWeek ) = "friday" then Day.Friday
                            else if Text.Lower( CalendarFirstDayOfWeek ) = "saturday" then Day.Saturday
                            else if Text.Lower( CalendarFirstDayOfWeek ) = "sunday" then Day.Sunday
                            else if CalendarFirstDayOfWeek <> null then error "参数错误:参数CalendarFirstDayOfWeek必须是Monday,Tuesday,Wednesday,Thursday,Friday,Saturday,Sunday中的一个。"
                            else Day.Monday ,
        
        // calendar list is here:
        
        CalendarList = { Number.From ( #date( Number.From( YearStart ) , 1 , 1 ) ) .. Number.From( #date( Number.From( YearEnd ) , 12, 31 ) ) },
        CalendarListTable = Table.FromList(CalendarList, Splitter.SplitByNothing(), null, null, ExtraValues.Error),
        #"Changed Type" = Table.TransformColumnTypes( CalendarListTable ,{{"Column1", type date}}),
        #"Renamed Columns" = Table.RenameColumns(#"Changed Type",{{"Column1", "Date"}}),

        Source = #"Renamed Columns",

        // build the Current Date
        CurrentDateTable  = 
        let
            DateStart = TheDate ,
            DateEnd = TheDate ,
            #"Added Custom" = Table.AddColumn(Source, "PeriodName", each if [Date] >= DateStart and [Date] <= List.Min( { DateEnd , TheDate } ) then "CurrentDate" else null , type text),
            #"Filtered Rows" = Table.SelectRows(#"Added Custom", each ([PeriodName] <> null)),
            #"Added PeriodNameCN" = Table.AddColumn(#"Filtered Rows", "PeriodNameCN", each "本日" , type text),
            #"Added PeriodTypeName" = Table.AddColumn(#"Added PeriodNameCN", "PeriodTypeName", each "Current", type text),
            #"Added PeriodTypeNameCN" = Table.AddColumn(#"Added PeriodTypeName", "PeriodTypeNameCN", each "本期", type text),
            #"Added PeriodTypeNameOrderBy" = Table.AddColumn(#"Added PeriodTypeNameCN", "PeriodTypeNameOrderBy", each 1 , Int64.Type ),
            #"Added PeriodNameOrderBy" = Table.AddColumn(#"Added PeriodTypeNameOrderBy", "PeriodNameOrderBy", each 1 , Int64.Type )
        in
            #"Added PeriodNameOrderBy",

        // build the Previous Date
        PreviousDateTable =
        let 
            DateStart = Date.AddDays( TheDate , -1 ) ,
            DateEnd = Date.AddDays( TheDate , -1 ) ,
            #"Added Custom" = Table.AddColumn(Source, "PeriodName", each if [Date] >= DateStart and [Date] <= List.Min( { DateEnd , TheDate } ) then "PreviousDate" else null , type text),
            #"Filtered Rows" = Table.SelectRows(#"Added Custom", each ([PeriodName] <> null)),
            #"Added PeriodNameCN" = Table.AddColumn(#"Filtered Rows", "PeriodNameCN", each "昨日" , type text),
            #"Added PeriodTypeName" = Table.AddColumn(#"Added PeriodNameCN", "PeriodTypeName", each "Previous", type text),
            #"Added PeriodTypeNameCN" = Table.AddColumn(#"Added PeriodTypeName", "PeriodTypeNameCN", each "上期", type text),
            #"Added PeriodTypeNameOrderBy" = Table.AddColumn(#"Added PeriodTypeNameCN", "PeriodTypeNameOrderBy", each 2 , Int64.Type ),
            #"Added PeriodNameOrderBy" = Table.AddColumn(#"Added PeriodTypeNameOrderBy", "PeriodNameOrderBy", each 1 , Int64.Type )
        in
            #"Added PeriodNameOrderBy",
        

        // build the Current Week
        CurrentWeekTable =
        let
            DateStart = Date.StartOfWeek( TheDate , FirstDayOfWeek ) ,
            DateEnd = Date.EndOfWeek( TheDate , FirstDayOfWeek ) ,
            #"Added Custom" = Table.AddColumn(Source, "PeriodName", each if [Date] >= DateStart and [Date] <= List.Min( { DateEnd , TheDate } ) then "CurrentWeek" else null , type text),
            #"Filtered Rows" = Table.SelectRows(#"Added Custom", each ([PeriodName] <> null)),
            #"Added PeriodNameCN" = Table.AddColumn(#"Filtered Rows", "PeriodNameCN", each "本周" , type text),
            #"Added PeriodTypeName" = Table.AddColumn(#"Added PeriodNameCN", "PeriodTypeName", each "Current", type text),
            #"Added PeriodTypeNameCN" = Table.AddColumn(#"Added PeriodTypeName", "PeriodTypeNameCN", each "本期", type text),
            #"Added PeriodTypeNameOrderBy" = Table.AddColumn(#"Added PeriodTypeNameCN", "PeriodTypeNameOrderBy", each 1 , Int64.Type ),
            #"Added PeriodNameOrderBy" = Table.AddColumn(#"Added PeriodTypeNameOrderBy", "PeriodNameOrderBy", each 2 , Int64.Type )
        in
            #"Added PeriodNameOrderBy",

        // build the Previous Week
        PreviousWeekTable =
        let
            DateStart = Date.StartOfWeek( Date.AddDays( TheDate , -7 ) , FirstDayOfWeek ) ,
            DateEnd = Date.EndOfWeek( Date.AddDays( TheDate , -7 ) , FirstDayOfWeek ) ,
            #"Added Custom" = Table.AddColumn(Source, "PeriodName", each if [Date] >=DateStart and [Date] <= DateEnd then "PreviousWeek" else null , type text),
            #"Filtered Rows" = Table.SelectRows(#"Added Custom", each ([PeriodName] <> null)),
            #"Added PeriodNameCN" = Table.AddColumn(#"Filtered Rows", "PeriodNameCN", each "上周" , type text),
            #"Added PeriodTypeName" = Table.AddColumn(#"Added PeriodNameCN", "PeriodTypeName", each "Previous", type text),
            #"Added PeriodTypeNameCN" = Table.AddColumn(#"Added PeriodTypeName", "PeriodTypeNameCN", each "上期", type text),
            #"Added PeriodTypeNameOrderBy" = Table.AddColumn(#"Added PeriodTypeNameCN", "PeriodTypeNameOrderBy", each 2 , Int64.Type ),
            #"Added PeriodNameOrderBy" = Table.AddColumn(#"Added PeriodTypeNameOrderBy", "PeriodNameOrderBy", each 2 , Int64.Type )
        in
            #"Added PeriodNameOrderBy",

        // build the Current Month
        CurrentMonthTable =
        let
            DateStart = Date.StartOfMonth( TheDate ) ,
            DateEnd = Date.EndOfMonth( TheDate ) ,
            #"Added Custom" = Table.AddColumn(Source, "PeriodName", each if [Date] >=DateStart and [Date] <= List.Min( { DateEnd , TheDate } ) then "CurrentMonth" else null , type text),
            #"Filtered Rows" = Table.SelectRows(#"Added Custom", each ([PeriodName] <> null)),
            #"Added PeriodNameCN" = Table.AddColumn(#"Filtered Rows", "PeriodNameCN", each "本月" , type text),
            #"Added PeriodTypeName" = Table.AddColumn(#"Added PeriodNameCN", "PeriodTypeName", each "Current", type text),
            #"Added PeriodTypeNameCN" = Table.AddColumn(#"Added PeriodTypeName", "PeriodTypeNameCN", each "本期", type text),
            #"Added PeriodTypeNameOrderBy" = Table.AddColumn(#"Added PeriodTypeNameCN", "PeriodTypeNameOrderBy", each 1 , Int64.Type ),
            #"Added PeriodNameOrderBy" = Table.AddColumn(#"Added PeriodTypeNameOrderBy", "PeriodNameOrderBy", each 3 , Int64.Type )
        in
            #"Added PeriodNameOrderBy",

        // build the Previous Month
        PreviousMonthTable =
        let
            DateStart = Date.StartOfMonth( Date.AddMonths( TheDate , -1 ) ) ,
            DateEnd = Date.EndOfMonth( Date.AddMonths( TheDate , -1 ) ) ,
            #"Added Custom" = Table.AddColumn(Source, "PeriodName", each if [Date] >=DateStart and [Date] <= List.Min( { DateEnd , TheDate } ) then "PreviousMonth" else null , type text),
            #"Filtered Rows" = Table.SelectRows(#"Added Custom", each ([PeriodName] <> null)),
            #"Added PeriodNameCN" = Table.AddColumn(#"Filtered Rows", "PeriodNameCN", each "上月" , type text),
            #"Added PeriodTypeName" = Table.AddColumn(#"Added PeriodNameCN", "PeriodTypeName", each "Previous", type text),
            #"Added PeriodTypeNameCN" = Table.AddColumn(#"Added PeriodTypeName", "PeriodTypeNameCN", each "上期", type text),
            #"Added PeriodTypeNameOrderBy" = Table.AddColumn(#"Added PeriodTypeNameCN", "PeriodTypeNameOrderBy", each 2 , Int64.Type ),
            #"Added PeriodNameOrderBy" = Table.AddColumn(#"Added PeriodTypeNameOrderBy", "PeriodNameOrderBy", each 3 , Int64.Type )
        in
            #"Added PeriodNameOrderBy",

        // combine table parts
        CombinedTable = Table.Combine( { CurrentDateTable , PreviousDateTable , CurrentWeekTable , PreviousWeekTable , CurrentMonthTable , PreviousMonthTable } )

    in
        CombinedTable

in
    Value.ReplaceType( fCreateCalendarPeriodRelative , CalendarPeriodRelativeType )

使用方法

复制上述M代码直接使用即可,如下:

即可。

©著作权归作者所有,转载或内容合作请联系作者
  • 序言:七十年代末,一起剥皮案震惊了整个滨河市,随后出现的几起案子,更是在滨河造成了极大的恐慌,老刑警刘岩,带你破解...
    沈念sama阅读 204,684评论 6 478
  • 序言:滨河连续发生了三起死亡事件,死亡现场离奇诡异,居然都是意外死亡,警方通过查阅死者的电脑和手机,发现死者居然都...
    沈念sama阅读 87,143评论 2 381
  • 文/潘晓璐 我一进店门,熙熙楼的掌柜王于贵愁眉苦脸地迎上来,“玉大人,你说我怎么就摊上这事。” “怎么了?”我有些...
    开封第一讲书人阅读 151,214评论 0 337
  • 文/不坏的土叔 我叫张陵,是天一观的道长。 经常有香客问我,道长,这世上最难降的妖魔是什么? 我笑而不...
    开封第一讲书人阅读 54,788评论 1 277
  • 正文 为了忘掉前任,我火速办了婚礼,结果婚礼上,老公的妹妹穿的比我还像新娘。我一直安慰自己,他们只是感情好,可当我...
    茶点故事阅读 63,796评论 5 368
  • 文/花漫 我一把揭开白布。 她就那样静静地躺着,像睡着了一般。 火红的嫁衣衬着肌肤如雪。 梳的纹丝不乱的头发上,一...
    开封第一讲书人阅读 48,665评论 1 281
  • 那天,我揣着相机与录音,去河边找鬼。 笑死,一个胖子当着我的面吹牛,可吹牛的内容都是我干的。 我是一名探鬼主播,决...
    沈念sama阅读 38,027评论 3 399
  • 文/苍兰香墨 我猛地睁开眼,长吁一口气:“原来是场噩梦啊……” “哼!你这毒妇竟也来了?” 一声冷哼从身侧响起,我...
    开封第一讲书人阅读 36,679评论 0 258
  • 序言:老挝万荣一对情侣失踪,失踪者是张志新(化名)和其女友刘颖,没想到半个月后,有当地人在树林里发现了一具尸体,经...
    沈念sama阅读 41,346评论 1 299
  • 正文 独居荒郊野岭守林人离奇死亡,尸身上长有42处带血的脓包…… 初始之章·张勋 以下内容为张勋视角 年9月15日...
    茶点故事阅读 35,664评论 2 321
  • 正文 我和宋清朗相恋三年,在试婚纱的时候发现自己被绿了。 大学时的朋友给我发了我未婚夫和他白月光在一起吃饭的照片。...
    茶点故事阅读 37,766评论 1 331
  • 序言:一个原本活蹦乱跳的男人离奇死亡,死状恐怖,灵堂内的尸体忽然破棺而出,到底是诈尸还是另有隐情,我是刑警宁泽,带...
    沈念sama阅读 33,412评论 4 321
  • 正文 年R本政府宣布,位于F岛的核电站,受9级特大地震影响,放射性物质发生泄漏。R本人自食恶果不足惜,却给世界环境...
    茶点故事阅读 39,015评论 3 307
  • 文/蒙蒙 一、第九天 我趴在偏房一处隐蔽的房顶上张望。 院中可真热闹,春花似锦、人声如沸。这庄子的主人今日做“春日...
    开封第一讲书人阅读 29,974评论 0 19
  • 文/苍兰香墨 我抬头看了看天上的太阳。三九已至,却和暖如春,着一层夹袄步出监牢的瞬间,已是汗流浃背。 一阵脚步声响...
    开封第一讲书人阅读 31,203评论 1 260
  • 我被黑心中介骗来泰国打工, 没想到刚下飞机就差点儿被人妖公主榨干…… 1. 我叫王不留,地道东北人。 一个月前我还...
    沈念sama阅读 45,073评论 2 350
  • 正文 我出身青楼,却偏偏与公主长得像,于是被迫代替她去往敌国和亲。 传闻我的和亲对象是个残疾皇子,可洞房花烛夜当晚...
    茶点故事阅读 42,501评论 2 343

推荐阅读更多精彩内容