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
ReportingGB11
Frequent Visitor

sum with DATESBETWEEN where lastdate parameter is determined via a slicer

Hi guys,

I'm facing difficulties calculating the sum of a column where the time boundaries of the sum are determined via a slicer:

The value I should get is the sum of 'Quantité N' from the lowest date up to the date determined by the slicer minus 1 year.

The current formula is the following:

Stock Physique N-1 V2 =
CALCULATE(SUM(SPHStockPF[Quantité N]), DATESBETWEEN(
'Date'[Date],
DATE(2018,12,31),
[Posting_date_n_1]
))
Where [Posting_date_n_1] is a measure that takes the max date of the slicer and return that date minus one year, its value is displayed below the slicer in the image.

 

wrong.PNG

So this formula gives me a result that i know is wrong because It does not stop the sum it should and when I use this formula

Stock Physique N-1 V2 =
CALCULATE(SUM(SPHStockPF[Quantité N]), DATESBETWEEN(
SPHStockPF[Posting Date],
DATE(2018,12,31),
DATE(2019,07,31)
)) 
I get different results (the good ones):
good.PNG
So my question is: how can I get the good results using the slicer related formula?
 
Thanks
1 ACCEPTED SOLUTION
v-zhenbw-msft
Community Support
Community Support

Hi @ReportingGB11 ,

 

We can create a measure to meet your requirement.

 

1. Firstly, we need to delete the relationship between SPHStockPF table and Date table.

Create a date slicer using Date table.

 

sum1.jpg

 

sum2.jpg

 

2. Then we can create a measure.

 

Stock Physique N-1 V2 = 
var _select = DATE(YEAR(MAX('Date'[Date]))-1,MONTH(MAX('Date'[Date])),DAY(MAX('Date'[Date])))
return
CALCULATE(SUM('SPHStockPF'[Quantité N]),FILTER('SPHStockPF','SPHStockPF'[Posting Date]>=DATE(2019,1,10) && 'SPHStockPF'[Posting Date]<=_select))

 

sum3.jpg

 

If it doesn’t meet your requirement, could you please show the exact expected result based on the table that you have shared?

 

Best regards,

 

Community Support Team _ zhenbw

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

 

BTW, pbix as attached.

View solution in original post

5 REPLIES 5
v-zhenbw-msft
Community Support
Community Support

Hi @ReportingGB11 ,

 

We can create a measure to meet your requirement.

 

1. Firstly, we need to delete the relationship between SPHStockPF table and Date table.

Create a date slicer using Date table.

 

sum1.jpg

 

sum2.jpg

 

2. Then we can create a measure.

 

Stock Physique N-1 V2 = 
var _select = DATE(YEAR(MAX('Date'[Date]))-1,MONTH(MAX('Date'[Date])),DAY(MAX('Date'[Date])))
return
CALCULATE(SUM('SPHStockPF'[Quantité N]),FILTER('SPHStockPF','SPHStockPF'[Posting Date]>=DATE(2019,1,10) && 'SPHStockPF'[Posting Date]<=_select))

 

sum3.jpg

 

If it doesn’t meet your requirement, could you please show the exact expected result based on the table that you have shared?

 

Best regards,

 

Community Support Team _ zhenbw

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

 

BTW, pbix as attached.

Thanks a lot for the help

amitchandak
Super User
Super User

@ReportingGB11 , Try like

Year behind Sales = CALCULATE(SUM(SPHStockPF[Quantité N]),dateadd('Date'[Date],-1,Year),'Date'[Date]>= DATE(2018,12,31))

 

Hope you need data > jan 2018

@amitchandak and @parry2k , many thanks for your replies.

 

However, I cannot display the solution provided by @amitchandak, the DATEADD function shows an error: It "expects a contiguous selection ....". Yet the Date table on which the DATEADD function is performed is a calendar table

parry2k
Super User
Super User

@ReportingGB11 if your goal is to get last year value, you can use many time intelligence functions like PARALLERPERIOD, SAMEPERIODLASTYEAR or DATESADD

 

for example

 

PY = CALCULATE ( [Your Measure], DATEADD ( DateTable[Date], -1, YEAR ) )

 

I would  Kudos if my solution helped. 👉 If you can spend time posting the question, you can also make efforts to give Kudos whoever helped to solve your problem. It is a token of appreciation!

Visit us at https://perytus.com, your one-stop-shop for Power BI-related projects/training/consultancy.



Subscribe to the @PowerBIHowTo YT channel for an upcoming video on List and Record functions in Power Query!!

Learn Power BI and Fabric - subscribe to our YT channel - Click here: @PowerBIHowTo

If my solution proved useful, I'd be delighted to receive Kudos. When you put effort into asking a question, it's equally thoughtful to acknowledge and give Kudos to the individual who helped you solve the problem. It's a small gesture that shows appreciation and encouragement! ❤


Did I answer your question? Mark my post as a solution. Proud to be a Super User! Appreciate your Kudos 🙂
Feel free to email me with any of your BI needs.

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.