- Subscribe to RSS Feed
- Mark Topic as New
- Mark Topic as Read
- Float this Topic for Current User
- Bookmark
- Subscribe
- Printer Friendly Page

- Mark as New
- Bookmark
- Subscribe
- Mute
- Subscribe to RSS Feed
- Permalink
- Report Inappropriate Content
Calculate WTD sales for same week last year, but for the same number of elapsed days
Hi!
Im struggeling with a time int. measure to calculate total sales last year. The main goal is to be able to show a table with [Department], [#Sales WTD] and [#Sales WTD_LY)] - without the need of any slicers at all, where the measure it self takes into account the current weeknumber based on NOW() / TODAY().
This is working fine with some easy measures, but my main problem is that [#Sales WTD_LY] calculates the sum for the whole week last year, and not for instance: only sales from monday until thursday (todays day). This makes it quite useless a KPI.
So - does anyone know how to take this into account?
Thanks! (Mock data set = https://ufile.io/uarzc)
(My week starts on Mondays FYI )
#SalesTotal = SUM([NetAmount])
#SalesTotal_LY = CALCULATE([#SalesTotal];DATEADD(Dates[Date];-1;YEAR))
#SalesWTD = CALCULATE([#SalesTotal]; FILTER( Dates; YEAR( Dates[Date] ) = YEAR( NOW() ) && WEEKNUM( Dates[Date];2 ) = WEEKNUM( NOW();2) ) )
#SalesWTD_LY = CALCULATE([#SalesTotal_LY]; FILTER( Dates; YEAR( Dates[Date] ) = YEAR( NOW() ) && WEEKNUM( (Dates[Date]);2 ) = WEEKNUM( NOW();2) ) )
Solved! Go to Solution.
- Mark as New
- Bookmark
- Subscribe
- Mute
- Subscribe to RSS Feed
- Permalink
- Report Inappropriate Content
@Anonymous,
Create the following columns in your Dates table.
WeekNumber = WEEKNUM(Dates[Date],2)
Year = YEAR(Dates[Date])
Then create the following measure in your sales table.
SameWeekLastYear = IF ( HASONEVALUE ( 'Dates'[Year] ) && HASONEVALUE ('Dates'[WeekNumber] ), CALCULATE( sales[#SalesTotal], FILTER ( ALL ( 'Dates' ), 'Dates'[Year] = VALUES ( 'Dates'[Year] )-1 && 'Dates'[WeekNumber] = VALUES ( 'Dates'[WeekNumber] ) && 'Dates'[WeekNumber] = WEEKNUM(NOW(),2 ) ) ))
Reference:
http://www.dutchdatadude.com/ultimate-time-based-calculations-cheat-sheet-for-dax-power-bi-including-week-based-calculations/
Regards,
Lydia
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
- Mark as New
- Bookmark
- Subscribe
- Mute
- Subscribe to RSS Feed
- Permalink
- Report Inappropriate Content
@Anonymous,
Create the following columns in your Dates table.
WeekNumber = WEEKNUM(Dates[Date],2)
Year = YEAR(Dates[Date])
Then create the following measure in your sales table.
SameWeekLastYear = IF ( HASONEVALUE ( 'Dates'[Year] ) && HASONEVALUE ('Dates'[WeekNumber] ), CALCULATE( sales[#SalesTotal], FILTER ( ALL ( 'Dates' ), 'Dates'[Year] = VALUES ( 'Dates'[Year] )-1 && 'Dates'[WeekNumber] = VALUES ( 'Dates'[WeekNumber] ) && 'Dates'[WeekNumber] = WEEKNUM(NOW(),2 ) ) ))
Reference:
http://www.dutchdatadude.com/ultimate-time-based-calculations-cheat-sheet-for-dax-power-bi-including-week-based-calculations/
Regards,
Lydia
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

Helpful resources
Join us at the Microsoft Fabric Community Conference
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!
Power BI Monthly Update - February 2025
Check out the February 2025 Power BI update to learn about new features.

Subject | Author | Posted | |
---|---|---|---|
04-14-2024 07:24 AM | |||
06-24-2024 08:39 PM | |||
01-17-2023 10:07 PM | |||
05-10-2024 12:46 PM | |||
05-30-2023 08:09 AM |