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

Compete to become Power BI Data Viz World Champion! First round ends August 18th. Get started.

Reply
Anonymous
Not applicable

How to make cumulative totals with changing parameters during time

Dear Friends,

I am trying to make cumulative totals of HR database where the employees during the time change their grades, salaries and cost center and this should be reflected in the cumulative totals over time but still count as one employee. For example for employee 100044 I should have it in cumulative total as 1 and not 5 but I for example if I want to present Cost center headcount breakdown this particular employees  will be until 01 April 2018 on CC-2 but after this date it should be on CC-16 and not double.

I have attached the file https://drive.google.com/file/d/1w2yhvbOX2FbMmoHa-21UkEdLd2XqYS23/view?usp=sharing 

Thank you very much in advance.

 

ngrulovic_0-1634155338787.png

ngrulovic_1-1634155713847.png

 

 

1 ACCEPTED SOLUTION
AllisonKennedy
Super User
Super User

@Anonymous Thanks for the sample file. 

I used method described here: https://excelwithallison.blogspot.com/2020/06/dax-approximate-lookup.html 

 

And I also replaced your Date table with one that has Month number for correct sorting: https://excelwithallison.blogspot.com/2020/04/dimdate-what-why-and-how.html 

If I understand correctly, I think this is what you're after:

 

I created a calculated column: 

Next Change Date =
VAR _EmpID = Database[Employee ID]
VAR _ChangeDate = Database[Change Date]
RETURN
MINX(FILTER(Database, Database[Change Date] > _ChangeDate && Database[Employee ID] = _EmpID), Database[Change Date])
 

and a measure:

Cumulative Total Head Count =
VAR _DateContext = MAX(Dates[Date])
RETURN
CALCULATE(
DISTINCTCOUNT( Database[Employee ID])
, FILTER(Database,
VAR _ChangeDate = Database[Change Date]
VAR _NextChangeDate =
VAR _EmpID = Database[Employee ID]
RETURN
MINX(FILTER(Database, Database[Change Date] > _ChangeDate && Database[Employee ID] = _EmpID && Database[Change Date] <=_DateContext), Database[Change Date])
RETURN
Database[Change Date] <= _DateContext
&& _NextChangeDate = BLANK()
&& (Database[Next Change Date] > _DateContext || Database[Next Change Date] = BLANK())
))
 
Then you can see Cumulative Head Count gradually increase, as Cost Center distribution changes (but doesn't double count anyone): 
 
AllisonKennedy_0-1634181863529.png

 

 

For your example Employee ID = 100044: 

 

AllisonKennedy_1-1634181908645.png

 

 

See sample file attached below signature. 


Please @mention me in your reply if you want a response.

Copying DAX from this post? Click here for a hack to quickly replace it with your own table names

Has this post solved your problem? Please Accept as Solution so that others can find it quickly and to let the community know your problem has been solved.
If you found this post helpful, please give Kudos C

I work as a Microsoft trainer and consultant, specialising in Power BI and Power Query.
www.excelwithallison.com

View solution in original post

3 REPLIES 3
Anonymous
Not applicable

Dear Alisson,

This is it! Thank you very much!

You're welcome!


Please @mention me in your reply if you want a response.

Copying DAX from this post? Click here for a hack to quickly replace it with your own table names

Has this post solved your problem? Please Accept as Solution so that others can find it quickly and to let the community know your problem has been solved.
If you found this post helpful, please give Kudos C

I work as a Microsoft trainer and consultant, specialising in Power BI and Power Query.
www.excelwithallison.com

AllisonKennedy
Super User
Super User

@Anonymous Thanks for the sample file. 

I used method described here: https://excelwithallison.blogspot.com/2020/06/dax-approximate-lookup.html 

 

And I also replaced your Date table with one that has Month number for correct sorting: https://excelwithallison.blogspot.com/2020/04/dimdate-what-why-and-how.html 

If I understand correctly, I think this is what you're after:

 

I created a calculated column: 

Next Change Date =
VAR _EmpID = Database[Employee ID]
VAR _ChangeDate = Database[Change Date]
RETURN
MINX(FILTER(Database, Database[Change Date] > _ChangeDate && Database[Employee ID] = _EmpID), Database[Change Date])
 

and a measure:

Cumulative Total Head Count =
VAR _DateContext = MAX(Dates[Date])
RETURN
CALCULATE(
DISTINCTCOUNT( Database[Employee ID])
, FILTER(Database,
VAR _ChangeDate = Database[Change Date]
VAR _NextChangeDate =
VAR _EmpID = Database[Employee ID]
RETURN
MINX(FILTER(Database, Database[Change Date] > _ChangeDate && Database[Employee ID] = _EmpID && Database[Change Date] <=_DateContext), Database[Change Date])
RETURN
Database[Change Date] <= _DateContext
&& _NextChangeDate = BLANK()
&& (Database[Next Change Date] > _DateContext || Database[Next Change Date] = BLANK())
))
 
Then you can see Cumulative Head Count gradually increase, as Cost Center distribution changes (but doesn't double count anyone): 
 
AllisonKennedy_0-1634181863529.png

 

 

For your example Employee ID = 100044: 

 

AllisonKennedy_1-1634181908645.png

 

 

See sample file attached below signature. 


Please @mention me in your reply if you want a response.

Copying DAX from this post? Click here for a hack to quickly replace it with your own table names

Has this post solved your problem? Please Accept as Solution so that others can find it quickly and to let the community know your problem has been solved.
If you found this post helpful, please give Kudos C

I work as a Microsoft trainer and consultant, specialising in Power BI and Power Query.
www.excelwithallison.com

Helpful resources

Announcements
July PBI25 Carousel

Power BI Monthly Update - July 2025

Check out the July 2025 Power BI update to learn about new features.

August 2025 community update carousel

Fabric Community Update - August 2025

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

Top Solution Authors