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

Shape the future of the Fabric Community! Your insights matter. That’s why we created a quick survey to learn about your experience finding answers to technical questions. Take survey.

Reply
bml123
Post Patron
Post Patron

Sum of sales from previous Monday until the date choosen

Hi,

 

I want to calculate sum of sales from Monday until now for weekly sales figures. How do I do that?

1 ACCEPTED SOLUTION

Hi @bml123 

 

You can try this measure

Total 3 =
VAR _selectDate = MAX ( 'Date'[Date] )
VAR _lastMonthEnd = EOMONTH ( _selectDate, -1 )
VAR _lastFridayDate =
    IF (
        WEEKDAY ( _lastMonthEnd, 2 ) >= 5,
        _lastMonthEnd - WEEKDAY ( _lastMonthEnd, 2 ) + 5,
        _lastMonthEnd - WEEKDAY ( _lastMonthEnd, 2 ) - 2
    )
VAR _mondayDate = _lastFridayDate + 3
RETURN
    CALCULATE (
        SUM ( SalesTable[Sales] ),
        ALL ( 'Date' ),
        DATESBETWEEN ( 'Date'[Date], _mondayDate, _selectDate )
    )

 

Best regard,

Jing

If this post helps, please Accept it as Solution to help other members find it.

View solution in original post

6 REPLIES 6
v-jingzhang
Community Support
Community Support

Hi @bml123 

 

Try this measure. When the selected date is Monday, it will only sum sales on that day. 

Total from Monday =
VAR _selectDate = MAX ( 'Date'[Date] )
VAR _mondayDate = _selectDate - WEEKDAY ( _selectDate, 2 ) + 1
RETURN
    CALCULATE (
        SUM ( SalesTable[Sales] ),
        ALL ( 'Date' ),
        DATESBETWEEN ( 'Date'[Date], _mondayDate, _selectDate )
    )

 

Or if you want to sum sales from previous Monday to this Monday when the selected date is Monday, you can try below one

Total from Previous Monday =
VAR _selectDate = MAX ( 'Date'[Date] )
VAR _weekDay = WEEKDAY ( _selectDate, 2 )
VAR _mondayDate =
    IF ( _weekDay = 1, _selectDate - 7, _selectDate - _weekDay + 1 )
RETURN
    CALCULATE (
        SUM ( SalesTable[Sales] ),
        ALL ( 'Date' ),
        DATESBETWEEN ( 'Date'[Date], _mondayDate, _selectDate )
    )

vjingzhang_0-1645065523646.png

 

Best Regards,
Community Support Team _ Jing
If this post helps, please Accept it as Solution to help other members find it.

Hi @v-jingzhang 

Thank you for the solution.  It worked perfectly fine.

Now I want to get the sum of sales from monday that comes after last friday of the previous month.

For example, for 13 January 2022, monday that comes after last friday of the previous month is 03/01/2022.

I want to get sum of sales from 03/01/2022 until 13 January 2022 if I select 13 January 2022 in the slicer.

How do I achieve that?

Hi @bml123 

 

You can try this measure

Total 3 =
VAR _selectDate = MAX ( 'Date'[Date] )
VAR _lastMonthEnd = EOMONTH ( _selectDate, -1 )
VAR _lastFridayDate =
    IF (
        WEEKDAY ( _lastMonthEnd, 2 ) >= 5,
        _lastMonthEnd - WEEKDAY ( _lastMonthEnd, 2 ) + 5,
        _lastMonthEnd - WEEKDAY ( _lastMonthEnd, 2 ) - 2
    )
VAR _mondayDate = _lastFridayDate + 3
RETURN
    CALCULATE (
        SUM ( SalesTable[Sales] ),
        ALL ( 'Date' ),
        DATESBETWEEN ( 'Date'[Date], _mondayDate, _selectDate )
    )

 

Best regard,

Jing

If this post helps, please Accept it as Solution to help other members find it.

Ashish_Mathur
Super User
Super User

Hi,

Create a Calendar Table with a relationhip from the Date column of the Data table to the Date column of the Calendar Table.  Create a slicer from the Date column of the Calendar Table and select a Date there.  Try this measure:

=calculate(sum(data[sales]),datesbetween(calendar[date],today()-weekday(min(calendar[date]),2)+1,min(calendar[date])))

 


Regards,
Ashish Mathur
http://www.ashishmathur.com
https://www.linkedin.com/in/excelenthusiasts/
bml123
Post Patron
Post Patron

Hi @amitchandak 

 

Sorry, your measure didn't work.  I have a slicer with all the dates from the calendar table and when I choose a date from the slicer, it should show me sum of sales from Monday until that day.  How do I achieve that?

 

amitchandak
Super User
Super User

@bml123 , You can use today or selected date

 

Week =
var _max1 = maxx(allselected('Date'), 'Date'[Date]) // or _max = today()
var _stweek = _max1 +-1*WEEKDAY(_max1,1)+1 //sunday week start
var _edweek= _max1+ 7-1*WEEKDAY(_max1,1)
return
calculate(sum(Table[Value]), filter(date, Date[Date] >=_stweek && Date[Date] <=_edweek))
// or use all date
//calculate(sum(Table[Value]), filter(all(date), Date[Date] >=_stweek && Date[Date] <=_edweek))

 

 

refer

Power BI — Week on Week and WTD
https://medium.com/@amitchandak.1978/power-bi-wtd-questions-time-intelligence-4-5-98c30fab69d3
https://community.powerbi.com/t5/Community-Blog/Week-Is-Not-So-Weak-WTD-Last-WTD-and-This-Week-vs-La...
https://www.youtube.com/watch?v=pnAesWxYgJ8

Join us as experts from around the world come together to shape the future of data and AI!
At the Microsoft Analytics Community Conference, global leaders and influential voices are stepping up to share their knowledge and help you master the latest in Microsoft Fabric, Copilot, and Purview.
️ November 12th-14th, 2024
 Online Event
Register Here

Helpful resources

Announcements
November Carousel

Fabric Community Update - November 2024

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

Dec Fabric Community Survey

We want your feedback!

Your insights matter. That’s why we created a quick survey to learn about your experience finding answers to technical questions.

Nov PBI Update Carousel

Power BI Monthly Update - November 2024

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

Live Sessions with Fabric DB

Be one of the first to start using Fabric Databases

Starting December 3, join live sessions with database experts and the Fabric product team to learn just how easy it is to get started.