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

The Power BI DataViz World Championships are on! With four chances to enter, you could win a spot in the LIVE Grand Finale in Las Vegas. Show off your skills.

Reply
eryka_90
Helper I
Helper I

How to create power query to filter out historical data

Hi All,

 

I would like to create new column in power query to have status "Recent Week", "Past Week" and "Null". The purpose of this is to filter out "Null" status from database.

   

Load Date Status
4/2/2024Recent Week
3/30/2024Past Week
3/25/2024Null
2/28/2024Null

 

I have created below query, however its return "Null" for all date. Is there something I miss out.

= let
Source = #"Renamed Columns3",
AddCalendar = Table.AddColumn(Source, "Weekday", each Date.DayOfWeek([Load Date], Day.Monday), type number),
AddWeekStart = Table.AddColumn(AddCalendar, "WeekStart", each Date.AddDays([Load Date], -[Weekday]), type date),
AddWeekNumber = Table.AddColumn(AddWeekStart, "WeekNumber", each Date.WeekOfYear([WeekStart]), type number),
CurrentWeek = Date.StartOfWeek(DateTime.LocalNow(), Day.Monday),
PrevWeek = Date.AddDays(CurrentWeek, -7),
AddCurrentWeekFlag = Table.AddColumn(AddWeekNumber, "CurrentWeekFlag", each if [WeekStart] = CurrentWeek then "Recent Week" else null, type text),
AddPrevWeekFlag = Table.AddColumn(AddCurrentWeekFlag, "PrevWeekFlag", each if [WeekStart] = PrevWeek then "Past Week" else null, type text),
CombineFlags = Table.AddColumn(AddPrevWeekFlag, "Check Current or Prior Wk", each if [CurrentWeekFlag] <> null then [CurrentWeekFlag] else if [PrevWeekFlag] <> null then [PrevWeekFlag] else null, type text),
RemoveExtraColumns = Table.RemoveColumns(CombineFlags, {"Weekday", "WeekStart", "WeekNumber", "CurrentWeekFlag", "PrevWeekFlag"})
in
RemoveExtraColumns

 

Thank you in advanced.

1 ACCEPTED SOLUTION
Anonymous
Not applicable

Hi @eryka_90 ,

First of all, many thanks to @amitchandak  for your very quick and effective replies.

 

Please try to create a custom column with below M code:

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMtG30DcyMDJRitUBcYwQHGN9YwNknpEpggdUBtMWCwA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"Load Date " = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Load Date ", type date}}),
    #"Added Custom" = Table.AddColumn(#"Changed Type", "Custom", each if Date.IsInCurrentWeek([#"Load Date "]) then "Recent Week" 
else if Date.IsInPreviousWeek([#"Load Date "]) then "Past Week" 
        else "Null")
in
    #"Added Custom"

vbinbinyumsft_0-1712559448521.png

Please refer the attached .pbix file.

 

Best regards,
Community Support Team_Binbin Yu
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

View solution in original post

4 REPLIES 4
Anonymous
Not applicable

Hi @eryka_90 ,

First of all, many thanks to @amitchandak  for your very quick and effective replies.

 

Please try to create a custom column with below M code:

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMtG30DcyMDJRitUBcYwQHGN9YwNknpEpggdUBtMWCwA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"Load Date " = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Load Date ", type date}}),
    #"Added Custom" = Table.AddColumn(#"Changed Type", "Custom", each if Date.IsInCurrentWeek([#"Load Date "]) then "Recent Week" 
else if Date.IsInPreviousWeek([#"Load Date "]) then "Past Week" 
        else "Null")
in
    #"Added Custom"

vbinbinyumsft_0-1712559448521.png

Please refer the attached .pbix file.

 

Best regards,
Community Support Team_Binbin Yu
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

amitchandak
Super User
Super User

@eryka_90 , based on the logic it will null, anything which is not current week or past week

 

you need to have logic like

if [WeekStart] = CurrentWeek then "Recent Week" else

if [WeekStart] = PrevWeek then "Past Week" else "Older weeks"

 

 

Full Power BI Video 20 Hours YouTube
Microsoft Fabric Series 60+ Videos YouTube
Microsoft Fabric Hindi End to End YouTube

@amitchandak 

 

I dont get it what you mean. Date 4/2/2024 is in current week, thus its should return value recent week instead of null. 

I did create a DAX using below script and its working fine. Its just i dont want to display blank on my visualization, then i plan to create this in power query.

Check Current or Prior Wk =
VAR _calendartable =
    ADDCOLUMNS (
        CALENDAR (
            DATE ( YEAR ( MIN ( 'Pending Items'[Load Date] ) ), 1, 1 ),
            DATE ( YEAR ( MAX ( 'Pending Items'[Load Date] ) ), 12, 31 )
        ),
        "Year", YEAR ( [Date] ),
        "Weeknumber", WEEKNUM ( [Date], 1 )
    )
VAR _currentweekyear =
    MAXX ( FILTER ( _calendartable, [Date] = TODAY () ), [Year] )
VAR _currentweekweeknumber =
    MAXX ( FILTER ( _calendartable, [Date] = TODAY () ), [Weeknumber] )
VAR _prevweekyear =
    MAXX ( FILTER ( _calendartable, [Date] = TODAY () - 7 ), [Year] )
VAR _prevweekweeknumber =
    MAXX ( FILTER ( _calendartable, [Date] = TODAY () - 7 ), [Weeknumber] )
VAR _currentweeklist =
    SUMMARIZE (
        FILTER (
            _calendartable,
            [Year] = _currentweekyear
                && [Weeknumber] = _currentweekweeknumber
        ),
        [Date]
    )
VAR _prevweeklist =
    SUMMARIZE (
        FILTER (
            _calendartable,
            [Year] = _prevweekyear
                && [Weeknumber] = _prevweekweeknumber
        ),
        [Date]
    )
RETURN
    SWITCH (
        TRUE (),
        'Pending Items'[Load Date] IN _currentweeklist, "Recent Week",
        'Pending Items'[Load Date] IN _prevweeklist, "Past Week"
    )

@eryka_90 , if use a measure and if that measure returns blank that value will not be shown in visual.

 

Likewise, I can filter on column having this week and last week and that will restrict the visual

Full Power BI Video 20 Hours YouTube
Microsoft Fabric Series 60+ Videos YouTube
Microsoft Fabric Hindi End to End YouTube

Helpful resources

Announcements
Feb2025 Sticker Challenge

Join our Community Sticker Challenge 2025

If you love stickers, then you will definitely want to check out our Community Sticker Challenge!

Jan NL Carousel

Fabric Community Update - January 2025

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