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
avanderschilden
Resolver I
Resolver I

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
Anonymous
Not applicable

[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

View solution in original post

6 REPLIES 6
Anonymous
Not applicable

[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

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

 

@Anonymous 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! 

 

Anonymous
Not applicable

"@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.

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!

Anonymous
Not applicable

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.
Greg_Deckler
Super User
Super User

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


@ 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.

Top Solution Authors