Running total with two pertinent Date columns

kbarb85

New Member
Joined
Nov 27, 2019
Messages
2
Office Version
  1. 365
Platform
  1. Windows
Hello all,
I believe I need DAX measure and I'm not finding what I need on the google machine. It's also possible I found what I need but did not comprehend it.
First of all, I'm using Excel (PQ & PPivot).

I have two tables. Here's the first:
Snag_b20b77.png

Note each employee can have multiple positions, each with a pos start and pos end (pos end = blank means the employee currently holds the position). Each position has an FTE allocation.
In the linked file (see below), this table is loaded into Power Query as Connection Only and also loaded to data model.

I also have a date table:
dates.png

Nothing too exciting. Just one column of continuous dates. This table is also loaded into PQ as Connection Only and also loaded to the data model.

I have not created any relationships or measures.

Okay, finally to the end goal.
I'd like my Users to filter by employee and get a line chart that shows the running total of FTE for all dates in the Date table.

So, if we take Kathy from the FTE table above, the chart would look something like this:
kathy fte.png


I think the tricky part is that the measure will have to "see" the pos start and pos end date. If a position end date exists, then the running total omits the FTE for that position as it iterates onward in time.

Here is a link the dummy file. Please feel free to make a copy and/or edit.

thank you in advance,
- Kurt
 

Excel Facts

How to find 2nd largest value in a column?
MAX finds the largest value. =LARGE(A:A,2) will find the second largest. =SMALL(A:A,3) will find the third smallest
Solution here.

DAX Measure:

Measure =
SUMX (
FILTER (
FTE,
FTE[Pos Start] <= MAX ( 'Calendar'[Date] )
&& (
FTE[Pos End] >= MAX ( 'Calendar'[Date] )
|| ISBLANK ( FTE[Pos End] )
)
),
FTE[FTE]
)
 
Upvote 0

Forum statistics

Threads
1,214,591
Messages
6,120,428
Members
448,961
Latest member
nzskater

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top