cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
Highlighted

SUMX over all dates within a month

Hello,

 

I have the following model;

 

Capture.PNG

 

 

 

 

 

 

 

 

 

 

I have a measure that calculates the number of reactivated users for each calendar date;

 

Reactivated Users = 
VAR _MaxDate =
    MAX ( 'D Calendar'[Date] )
VAR _CurrentUsers =
    CALCULATETABLE ( VALUES ( 'F Orders'[UserId] ), 'D Order'[IsCompleted] = "Yes" )
VAR _UserBefore60Days =
    CALCULATETABLE (
        VALUES ( 'F Orders'[UserId] ),
        'D Calendar'[Date] < _MaxDate - 60,
        'D Order'[IsCompleted] = "Yes"
    )
VAR _UsersLast60Days =
    CALCULATETABLE (
        VALUES ( 'F Orders'[UserId] ),
        'D Calendar'[Date] >= _MaxDate - 60
            && 'D Calendar'[Date] <= _MaxDate - 1,
        'D Order'[IsCompleted] = "Yes"
    )
VAR _Result =
    CALCULATE (
        DISTINCTCOUNT ( 'F Orders'[UserId] ),
        FILTER (
            ALL ( 'F Orders'[UserId] ),
            'F Orders'[UserId] IN _CurrentUsers
                && 'F Orders'[UserId] IN _UserBefore60Days
                && NOT 'F Orders'[UserId] IN _UsersLast60Days
        )
    )
RETURN
    _Result

 

I would like to display the total sum of all dates as the total for the month;

 

Capture.PNG

 

 

 

 

 

 

 

 

 

 

 

Does anyone have an idea how to achieve the desired result?

 

Many thanks in advance!

1 ACCEPTED SOLUTION

Accepted Solutions
Super User
Super User

Re: SUMX over all dates within a month

[Reactivated Users - Helper Measure] = -- hidden measure
// This measure works correctly on an individual
// day level.
VAR _MaxDate = MAX ( 'D Calendar'[Date] )
VAR _CurrentUsers =
    CALCULATETABLE (
    	VALUES ( 'F Orders'[UserId] ), 
    	'D Order'[IsCompleted] = "Yes" 
    )
VAR _UsersBefore60Days =
    CALCULATETABLE (
        VALUES ( 'F Orders'[UserId] ),
        'D Calendar'[Date] < _MaxDate - 60,
        'D Order'[IsCompleted] = "Yes"
    )
VAR _UsersLast60Days =
    CALCULATETABLE (
        VALUES ( 'F Orders'[UserId] ),
        'D Calendar'[Date] >= _MaxDate - 60,
        'D Calendar'[Date] <= _MaxDate - 1,
        'D Order'[IsCompleted] = "Yes"
    )
VAR _UsersOfInterest =
	except(
		intersect(
	            _CurrentUsers,
	            _UsersBefore60Days		
		),
		_UsersLast60Days
	)
VAR _Result = countrows ( _UsersOfInterest )
RETURN
    _Result
    
    
[Reactivated Users] =
var __reactivatedUserCount =
	sumx(
		'D Calendar',
		[Reactivated Users - Helper Measure]
	)
return
	__reactivatedUserCount
6 REPLIES 6
Super User
Super User

Re: SUMX over all dates within a month

This looks like a measure totals problem. Very common. See my post about it here: https://community.powerbi.com/t5/DAX-Commands-and-Tips/Dealing-with-Measure-Totals/td-p/63376

Also, this Quick Measure, Measure Totals, The Final Word should get you what you need:
https://community.powerbi.com/t5/Quick-Measures-Gallery/Measure-Totals-The-Final-Word/m-p/547907


I have book! Learn Power BI from Packt


Did I answer your question? Mark my post as a solution!

Proud to be a Datanaut!

Super User
Super User

Re: SUMX over all dates within a month

[Reactivated Users - Helper Measure] = -- hidden measure
// This measure works correctly on an individual
// day level.
VAR _MaxDate = MAX ( 'D Calendar'[Date] )
VAR _CurrentUsers =
    CALCULATETABLE (
    	VALUES ( 'F Orders'[UserId] ), 
    	'D Order'[IsCompleted] = "Yes" 
    )
VAR _UsersBefore60Days =
    CALCULATETABLE (
        VALUES ( 'F Orders'[UserId] ),
        'D Calendar'[Date] < _MaxDate - 60,
        'D Order'[IsCompleted] = "Yes"
    )
VAR _UsersLast60Days =
    CALCULATETABLE (
        VALUES ( 'F Orders'[UserId] ),
        'D Calendar'[Date] >= _MaxDate - 60,
        'D Calendar'[Date] <= _MaxDate - 1,
        'D Order'[IsCompleted] = "Yes"
    )
VAR _UsersOfInterest =
	except(
		intersect(
	            _CurrentUsers,
	            _UsersBefore60Days		
		),
		_UsersLast60Days
	)
VAR _Result = countrows ( _UsersOfInterest )
RETURN
    _Result
    
    
[Reactivated Users] =
var __reactivatedUserCount =
	sumx(
		'D Calendar',
		[Reactivated Users - Helper Measure]
	)
return
	__reactivatedUserCount

Re: SUMX over all dates within a month

Dear Power BI team, give this man @darlove a statue for his contribution to this forum!

 

@darlove why is the daily number of reactivated users different from my first measure with a monthly total of 2226?

 

@Greg_Deckler  thanks for your reply and interesting posts! 

 

Super User
Super User

Re: SUMX over all dates within a month

"@darlove why is the daily number of reactivated users different from my first measure with a monthly total of 2226?"

I don't know. Is this wrong? You said you wanted to sum up all the reactivated users for all the days in the month in order to get the total for the month. This is what the measure does. Doesn't it?

Best
D.

Re: SUMX over all dates within a month

The total sum of the daily numbers is correct. It is matching with a manual addition of all days so thanks a lot for that.

 

My doubts are based on the fact that your measure is producing a different daily result than my old measure, and I'm not sure which change you made in the new measure is creating this difference. Anyway, thanks again!

Super User
Super User

Re: SUMX over all dates within a month

To know which is right you have to manually and carefully calculate the measure for some of the days. Take those days where there is a difference between the measures.

Best
D.

Helpful resources

Announcements
Virtual Launch Event

Microsoft Business Applications October Virtual Launch Event

Join us for an in-depth look at the new innovations across Dynamics 365 and the Microsoft Power Platform.

Power BI Helps Homeless and Trouble Youth

Power BI Helps Homeless and Trouble Youth

We spoke with Power BI Super User, Greg Deckler, about his charity work

MBAS Gallery

Watch Sessions On Demand!

Continue your learning in our online communities.

Users Online
Currently online: 393 members 4,229 guests
Please welcome our newest community members: