Running total with two pertinent Date columns

kbarb85

New Member
Joined
Nov 27, 2019
Messages
2
Office Version
365
Platform
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
 

kbarb85

New Member
Joined
Nov 27, 2019
Messages
2
Office Version
365
Platform
Windows
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]
)
 

Forum statistics

Threads
1,078,474
Messages
5,340,551
Members
399,383
Latest member
rahmanab001

Some videos you may like

This Week's Hot Topics

  • Problem with Radio Button's format control
    I am creating an employee evaluation template (a sample is below) Column A is the category Column B, C D, E and F will be ratings (unacceptable...
  • Last Display on userform to a Listbox
    [CODE=vba] lstdisplay.ColumnCount = 15 lstdisplay.RowSource = "A1:O600000" [/CODE] So when i do this it Displays everything on the sheet i am...
  • Rename and move files to a new location
    Dear all, I have an excel file with the following information. The actual file name is at column A but i want to rename it using the following...
  • Help with True/False Formula
    Hello! Am stumped how to fix this formula, in which my result returns 'True', but it should return False. =IF(AG2=True...
  • Clear extra characters from a provided range of cells
    Dear All, I have following code which gives me desired output to remove extra characters from a provided range. But it takes too much time when...
  • Help with Current and highest streaks
    Hi there, I've just joined the forum and this is my first post. I've already spent quite a bit of time searching the net and this forum for a...
Top