Hi,
I have been trying to plot the evolution of old ticket backlog in a chart (i.e. I want to be able to see how many tickets older than X days were open every day, in the past 2 years), and so far I have been able to plot the evolution of all backlog (regardless of its age) in a chart (with DimDate[FullDate] in the X axis) with the following measure:
BacklogOverTime =
IF ( MAX ( 'DimDate'[FullDate]) <= MAX(FactCases[CreatedDate] ),
COUNTROWS (
FILTER (
FactCases,
FactCases[CreatedDate] <= MAX('DimDate'[FullDate]) &&
( FactCases[ClosedDate] > MAX('DimDate'[FullDate]) || ISBLANK( FactCases[ClosedDate]))
)
)
)
I tried to add another AND condition into the COUNTROWS filter formula like the following (I was trying to only capture tickets older than 120 days), but I am not getting any result when I add it:
DATEDIFF(MAX('DimDate'[FullDate]),FactCases[CreatedDate],DAY)>120
Appreciate any help if anyone is familiar with these types of calculations.
Thanks.
Solved! Go to Solution.
I just realized that I was using the last filter wrong, and DATEDIFF needed the 'FactCases'[CreatedDate] first. I'll leave the final formula I came up with here in case it is of use for anyone in the future.
BacklogOverTime_120+ =
IF ( MAX ( 'DimDate'[FullDate]) <= MAX(FactCases[CreatedDate] ),
COUNTROWS (
FILTER (
FactCases,
FactCases[CreatedDate] <= MAX('DimDate'[FullDate]) &&
DATEDIFF(FactCases[CreatedDate],MAX('DimDate'[FullDate]),DAY)>120 &&
( FactCases[ClosedDate] > MAX('DimDate'[FullDate]) || ISBLANK( FactCases[ClosedDate] ))
)
)
)
I just realized that I was using the last filter wrong, and DATEDIFF needed the 'FactCases'[CreatedDate] first. I'll leave the final formula I came up with here in case it is of use for anyone in the future.
BacklogOverTime_120+ =
IF ( MAX ( 'DimDate'[FullDate]) <= MAX(FactCases[CreatedDate] ),
COUNTROWS (
FILTER (
FactCases,
FactCases[CreatedDate] <= MAX('DimDate'[FullDate]) &&
DATEDIFF(FactCases[CreatedDate],MAX('DimDate'[FullDate]),DAY)>120 &&
( FactCases[ClosedDate] > MAX('DimDate'[FullDate]) || ISBLANK( FactCases[ClosedDate] ))
)
)
)
User | Count |
---|---|
110 | |
63 | |
61 | |
37 | |
37 |
User | Count |
---|---|
112 | |
67 | |
63 | |
60 | |
50 |