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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
gladies123
Helper I
Helper I

Reg: WTD

hi Team,

We need an solution for WTD   

Example

if i select any date ex:(18/08/2021) from slicer it should consider the start of the week that is (15/08/2021-sunday), so it should return (15/08/2021-18/08/2021).

kindly help me on this 

 

thanks,

Gladis

1 ACCEPTED SOLUTION
v-rzhou-msft
Community Support
Community Support

Hi @gladies123 

I think you need to build a date table and add a custom weeknum column and a custom year column in it by dax. If you use weeknum function directly, you will get wrong weeknum at the end of the previous year and the beginning of the next year.

For example: 

In my Sample I let week start on Sunday.

2020/12/31,2021/01/01,2021/01/02 are in the same weeknum, but weeknum function will give you 53 in 2020 and 1 in 2021. It's wrong result.

Firstly build a calendar table by dax.

Date = 
ADDCOLUMNS (
    CALENDAR ( DATE ( 2019, 01, 01 ), DATE ( 2021, 12, 31 ) ),
    "Year", YEAR ( [Date] ),
    "Month", MONTH ( [Date] ),
    "WeekNum", WEEKNUM ( [Date], 1 ),
    "WeekDay", WEEKDAY ( [Date], 1 ),
    "MonthName", FORMAT ( [Date], "MMMM" ),
    "DayName", FORMAT ( [Date], "DDDD" )
)

Add calculated columns in it to get correct weeknum and year.

ISO 8601 WeekNum = 
VAR _COUNT0 =
    CALCULATE (
        COUNTROWS ( 'Date' ),
        FILTER (
            'Date',
            'Date'[Year] = EARLIER ( 'Date'[Year] )
                && 'Date'[WeekNum] - 1 = 0
        )
    )
VAR _BASENUM1 =
    IF ( _COUNT0 < 7, 'Date'[WeekNum] - 1, 'Date'[WeekNum] )
VAR _ISO_8601_WeekNum =
    IF (
        WEEKDAY ( DATE ( 'Date'[Year] - 1, 01, 01 ) ) <> 1
            && 'Date'[Year] = 'Date'[Year]
            && _BASENUM1 = 0,
        WEEKNUM ( DATE ( MIN ( 'Date'[Year] ), 12, 31 ), 1 ) - 1,
        _BASENUM1
    )
RETURN
    _ISO_8601_WeekNum
ISO WeekYear = 
VAR _COUNT0 =
    CALCULATE (
        COUNTROWS ( 'Date' ),
        FILTER (
            'Date',
            'Date'[Year] = EARLIER ( 'Date'[Year] )
                && 'Date'[WeekNum] - 1 = 0
        )
    )
VAR _BASENUM1 =
    IF ( _COUNT0 < 7, 'Date'[WeekNum] - 1, 'Date'[WeekNum] )
RETURN
IF(_BASENUM1 = 0,'Date'[Year] -1,'Date'[Year])

Build a relationship between this table and your Data table.

Then build a measure to calculate WTD.

WTD =
VAR _SELECTISOYEAR =
    SELECTEDVALUE ( 'Date'[ISO WeekYear] )
VAR _SELECTISOWEEKNUM =
    SELECTEDVALUE ( 'Date'[ISO 8601 WeekNum] )
RETURN
    CALCULATE (
        SUM ( Data[Value] ),
        FILTER (
            ALL ( 'Date' ),
            'Date'[ISO 8601 WeekNum] = _SELECTISOWEEKNUM
                && 'Date'[ISO WeekYear] = _SELECTISOYEAR
        )
    )

Result is sum between 2021/08/15 - 2021/08/21.

1.png

1.png

 

Best Regards,
Rico Zhou

 

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

2 REPLIES 2
v-rzhou-msft
Community Support
Community Support

Hi @gladies123 

I think you need to build a date table and add a custom weeknum column and a custom year column in it by dax. If you use weeknum function directly, you will get wrong weeknum at the end of the previous year and the beginning of the next year.

For example: 

In my Sample I let week start on Sunday.

2020/12/31,2021/01/01,2021/01/02 are in the same weeknum, but weeknum function will give you 53 in 2020 and 1 in 2021. It's wrong result.

Firstly build a calendar table by dax.

Date = 
ADDCOLUMNS (
    CALENDAR ( DATE ( 2019, 01, 01 ), DATE ( 2021, 12, 31 ) ),
    "Year", YEAR ( [Date] ),
    "Month", MONTH ( [Date] ),
    "WeekNum", WEEKNUM ( [Date], 1 ),
    "WeekDay", WEEKDAY ( [Date], 1 ),
    "MonthName", FORMAT ( [Date], "MMMM" ),
    "DayName", FORMAT ( [Date], "DDDD" )
)

Add calculated columns in it to get correct weeknum and year.

ISO 8601 WeekNum = 
VAR _COUNT0 =
    CALCULATE (
        COUNTROWS ( 'Date' ),
        FILTER (
            'Date',
            'Date'[Year] = EARLIER ( 'Date'[Year] )
                && 'Date'[WeekNum] - 1 = 0
        )
    )
VAR _BASENUM1 =
    IF ( _COUNT0 < 7, 'Date'[WeekNum] - 1, 'Date'[WeekNum] )
VAR _ISO_8601_WeekNum =
    IF (
        WEEKDAY ( DATE ( 'Date'[Year] - 1, 01, 01 ) ) <> 1
            && 'Date'[Year] = 'Date'[Year]
            && _BASENUM1 = 0,
        WEEKNUM ( DATE ( MIN ( 'Date'[Year] ), 12, 31 ), 1 ) - 1,
        _BASENUM1
    )
RETURN
    _ISO_8601_WeekNum
ISO WeekYear = 
VAR _COUNT0 =
    CALCULATE (
        COUNTROWS ( 'Date' ),
        FILTER (
            'Date',
            'Date'[Year] = EARLIER ( 'Date'[Year] )
                && 'Date'[WeekNum] - 1 = 0
        )
    )
VAR _BASENUM1 =
    IF ( _COUNT0 < 7, 'Date'[WeekNum] - 1, 'Date'[WeekNum] )
RETURN
IF(_BASENUM1 = 0,'Date'[Year] -1,'Date'[Year])

Build a relationship between this table and your Data table.

Then build a measure to calculate WTD.

WTD =
VAR _SELECTISOYEAR =
    SELECTEDVALUE ( 'Date'[ISO WeekYear] )
VAR _SELECTISOWEEKNUM =
    SELECTEDVALUE ( 'Date'[ISO 8601 WeekNum] )
RETURN
    CALCULATE (
        SUM ( Data[Value] ),
        FILTER (
            ALL ( 'Date' ),
            'Date'[ISO 8601 WeekNum] = _SELECTISOWEEKNUM
                && 'Date'[ISO WeekYear] = _SELECTISOYEAR
        )
    )

Result is sum between 2021/08/15 - 2021/08/21.

1.png

1.png

 

Best Regards,
Rico Zhou

 

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

Check out the April 2024 Power BI update to learn about new features.

April Fabric Community Update

Fabric Community Update - April 2024

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