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

Earn the coveted Fabric Analytics Engineer certification. 100% off your exam for a limited time only!

Reply
MCacc
Helper III
Helper III

Sum between two dates, ignoring the dates before my start of the year

Hello, 

I have to calculate a SUM of my new clients between two dates. 

- The date I choose from my filter

- The first day of the year of the date I choose from my filter 

 

So for example, the date I choose from my filter is 23/05/2020. So my SUM has to be between 1/01/2020 and 23/05/2020. This SUM doesn't have to include all the dates before 1/01/2020.

 

So I did something like that: 

Measure = CALCULATE(SUM('Table'[MY_NEW_CLIENTS);FILTER(ALLEXCEPT('TABLE';'TABLE'[CLIENT_TYPE_ID]); 'TABLE'[DATE] >= STARTOFYEAR('TABE'[DATE])&&'TABLE'[DATE] <=SELECTEDVALUE('TABLE'[DATE])))
 
The issue is, this measure also gives me the sum of all dates before my startoftheyear, whilst it should return only the sum between 1/01/2020 and 23/05/2020
 
Any ideas? 
 
Thank you
 
 
2 ACCEPTED SOLUTIONS
Greg_Deckler
Super User
Super User

@MCacc - 

Perhaps:

Measure =
  VAR __Date = SELECTEDVALUE('Table'[DATE])
  VAR __First = DATE(YEAR(__Date),1,1)
RETURN
  SUMX(FILTER('Table',[DATE] >= __First && [DATE] <= __Date),[MY_NEW_CLIENTS])

@ me in replies or I'll lose your thread!!!
Instead of a Kudo, please vote for this idea
Become an expert!: Enterprise DNA
External Tools: MSHGQM
YouTube Channel!: Microsoft Hates Greg
Latest book!:
Mastering Power BI 2nd Edition

DAX is easy, CALCULATE makes DAX hard...

View solution in original post

v-xicai
Community Support
Community Support

Hi @MCacc ,

 

You may create measure like DAX below.

 

Measure =

Var _FilterDate= SELECTEDVALUE( 'TABE'[DATE])

Var _FirstDate= DATE(YEAR ( 'TABE'[DATE]) , 1,1)

Return

CALCULATE(SUM('Table'[MY_NEW_CLIENTS),FILTER(ALLEXCEPT('TABLE', 'TABLE'[CLIENT_TYPE_ID]), 'TABLE'[DATE] >= _FirstDate&&'TABLE'[DATE] <=_FilterDate))

 

Best Regards,

Amy 

 

Community Support Team _ Amy

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
v-xicai
Community Support
Community Support

Hi @MCacc ,

 

You may create measure like DAX below.

 

Measure =

Var _FilterDate= SELECTEDVALUE( 'TABE'[DATE])

Var _FirstDate= DATE(YEAR ( 'TABE'[DATE]) , 1,1)

Return

CALCULATE(SUM('Table'[MY_NEW_CLIENTS),FILTER(ALLEXCEPT('TABLE', 'TABLE'[CLIENT_TYPE_ID]), 'TABLE'[DATE] >= _FirstDate&&'TABLE'[DATE] <=_FilterDate))

 

Best Regards,

Amy 

 

Community Support Team _ Amy

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

@MCacc , is that not YTD ?

Example

YTD Sales = CALCULATE(SUM(Sales[Sales Amount]),DATESYTD(('Date'[Date]),"12/31"))

To get the best of the time intelligence function. Make sure you have a date calendar and it has been marked as the date in model view. Also, join it with the date column of your fact/s. Refer :
https://radacad.com/creating-calendar-table-in-power-bi-using-dax-functions
https://www.archerpoint.com/blog/Posts/creating-date-table-power-bi
https://www.sqlbi.com/articles/creating-a-simple-date-table-in-dax/

See if my webinar on Time Intelligence can help: https://community.powerbi.com/t5/Webinars-and-Video-Gallery/PowerBI-Time-Intelligence-Calendar-WTD-Y...


Appreciate your Kudos.

Thank you amitchandak! This worked perfectly for me. I had an excel file that is connceted to power bi and is formatted like a balance sheet so just numbers that need to be summed in order to get the number for the certain month.  I also tried one other solution in this post before trying yours and this was the lucky one!

Greg_Deckler
Super User
Super User

@MCacc - 

Perhaps:

Measure =
  VAR __Date = SELECTEDVALUE('Table'[DATE])
  VAR __First = DATE(YEAR(__Date),1,1)
RETURN
  SUMX(FILTER('Table',[DATE] >= __First && [DATE] <= __Date),[MY_NEW_CLIENTS])

@ me in replies or I'll lose your thread!!!
Instead of a Kudo, please vote for this idea
Become an expert!: Enterprise DNA
External Tools: MSHGQM
YouTube Channel!: Microsoft Hates Greg
Latest book!:
Mastering Power BI 2nd Edition

DAX is easy, CALCULATE makes DAX hard...

Helpful resources

Announcements
April AMA free

Microsoft Fabric AMA Livestream

Join us Tuesday, April 09, 9:00 – 10:00 AM PST for a live, expert-led Q&A session on all things Microsoft Fabric!

March Fabric Community Update

Fabric Community Update - March 2024

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