cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
ElastBI Frequent Visitor
Frequent Visitor

Sum of values between two variable dates

Hello all,

 

In my Power BI Desktop file I try to create measures that calculate and outstanding amount between days of a due date. I want to create 4 measures:

 

  1. Today to today -30 days
  2. Today -31 days to today -60 days
  3. Today -61 to Today -90 days
  4. Today - 90 days and further.

I have to use two columns: "Due date" and "Outstanding amount". I created the formule for the "measure 1". The formula goes as follows:

 

0 -30 days = CALCULATE (
SUM ( 'debtchase-report'[Outstanding Amount] ),
FILTER (
ALL ( 'debtchase-report'[Due Date] ),
'debtchase-report'[Due Date]
> TODAY() - 30))
 
This formula works for me however I can't seem to find the formulas for the others measures I need to calculate. Can someone help me?
 
Thanks in advance!
 
Best regards

 

 

1 ACCEPTED SOLUTION

Accepted Solutions
Highlighted
Community Support Team
Community Support Team

Re: Sum of values between two variable dates

hi, @ElastBI 

You use the same logic for other measures as below:

Today -31 days to today -60 days = CALCULATE (
SUM ( 'debtchase-report'[Outstanding Amount] ),
FILTER (
ALL ( 'debtchase-report'[Due Date] ),
'debtchase-report'[Due Date]
> TODAY() - 60&&'debtchase-report'[Due Date]
<= TODAY() - 31))
Today -61 days to today -90 days = CALCULATE (
SUM ( 'debtchase-report'[Outstanding Amount] ),
FILTER (
ALL ( 'debtchase-report'[Due Date] ),
'debtchase-report'[Due Date]
> TODAY() - 90&&'debtchase-report'[Due Date]
<= TODAY() - 61))
Today - 90 days and further = CALCULATE (
SUM ( 'debtchase-report'[Outstanding Amount] ),
FILTER (
ALL ( 'debtchase-report'[Due Date] ),
'debtchase-report'[Due Date]<= TODAY() - 90))

If not your case, please share some simple sample data and expected output.

 

Best Regards,

Lin

Community Support Team _ Lin
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
Highlighted
Community Support Team
Community Support Team

Re: Sum of values between two variable dates

hi, @ElastBI 

You use the same logic for other measures as below:

Today -31 days to today -60 days = CALCULATE (
SUM ( 'debtchase-report'[Outstanding Amount] ),
FILTER (
ALL ( 'debtchase-report'[Due Date] ),
'debtchase-report'[Due Date]
> TODAY() - 60&&'debtchase-report'[Due Date]
<= TODAY() - 31))
Today -61 days to today -90 days = CALCULATE (
SUM ( 'debtchase-report'[Outstanding Amount] ),
FILTER (
ALL ( 'debtchase-report'[Due Date] ),
'debtchase-report'[Due Date]
> TODAY() - 90&&'debtchase-report'[Due Date]
<= TODAY() - 61))
Today - 90 days and further = CALCULATE (
SUM ( 'debtchase-report'[Outstanding Amount] ),
FILTER (
ALL ( 'debtchase-report'[Due Date] ),
'debtchase-report'[Due Date]<= TODAY() - 90))

If not your case, please share some simple sample data and expected output.

 

Best Regards,

Lin

Community Support Team _ Lin
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

Super User
Super User

Re: Sum of values between two variable dates

Hi,

Build a Calendar Table and create a relationship from the Due Date column of the debtchase-report Table to the Date column of the Calendar Table.  Write these measures

0-30 days = CALCULATE(SUM ( 'debtchase-report'[Outstanding Amount]),DATESBETWEEN(Calendar[Date],TODAY()-30,TODAY()))
31-60 days = CALCULATE(SUM ( 'debtchase-report'[Outstanding Amount]),DATESBETWEEN(Calendar[Date],TODAY()-60,TODAY()-31))
61-90 days = CALCULATE(SUM ( 'debtchase-report'[Outstanding Amount]),DATESBETWEEN(Calendar[Date],TODAY()-90,TODAY()-61))
90 days+ = CALCULATE(SUM ( 'debtchase-report'[Outstanding Amount]),DATESBETWEEN(Calendar[Date],MINX(ALL(Calendar),Calendar[Date]),TODAY()-91))
Hope this helps.

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

Helpful resources

Announcements
Ask Amir Anything

Exclusive LIVE Community Event No. 2 – Ask Amir Anything

Next in our Triple A series: Ask Amir Netz questions about the latest updates, features and future.

Ask Amanda Anything Q&A

Ask Amanda Anything Q&A

Learn the answers to some of the questions asked during the Amanda Triple A event.

October 2019 Community Highlights

October 2019 Community Highlights

October was a busy month in the community. Read the recap article to learn about some of the events and content.

New Solution Badges

New Solution Badges

Two waves of brand new solution badges are coming! Read the article for more information on our new community badges.

Users Online
Currently online: 154 members 1,671 guests
Please welcome our newest community members: