Check your eligibility for this 50% exam voucher offer and join us for free live learning sessions to get prepared for Exam DP-700.
Get StartedDon't miss out! 2025 Microsoft Fabric Community Conference, March 31 - April 2, Las Vegas, Nevada. Use code MSCUST for a $150 discount. Prices go up February 11th. Register now.
Hello,
I need some help in creating a measure that caluclates the average value at a certain time for the past 3 days. In my current line graph, I've got different times of the day on the x-axis and the number of calls on the y-axis. I also have a filter on the visual that selects which day to show the data for.
For e.g. lets say the line graph above is filtered for the day of 5th November 2024. The datapoint on the average line graph at 9am will look at the number of calls at 9am on the 4th November, number of calls at 9am on the 3rd November and number of calls at 9am on the 2nd November and find the average of these numbers.
Appreciate any help I can get, thank you!
Solved! Go to Solution.
Hi @yuvan29
Measure can only return one value at a date point, so I create 4 measures.
Here's the sample:
Table:
Last day =
VAR _currentTime = MAX('Table 2'[Time])
VAR _today = DATE(YEAR(MAX('Table'[Date\Time])), MONTH(MAX('Table'[Date\Time])), DAY(MAX('Table'[Date\Time])))
VAR _previousday = CALCULATE(
MAX('Table'[Date\Time].[Date]),
FILTER(
ALL('Table'),
DATE(YEAR('Table'[Date\Time]), MONTH('Table'[Date\Time]), DAY('Table'[Date\Time])) < _today
)
)
RETURN
CALCULATE(
SUM('Table'[Values]),
FILTER(
ALL('Table'),
TIME(
HOUR('Table'[Date\Time]),
MINUTE('Table'[Date\Time]),
SECOND('Table'[Date\Time])
) = _currentTime && DATE(YEAR('Table'[Date\Time]), MONTH('Table'[Date\Time]), DAY('Table'[Date\Time])) = _previousday
)
)
Last 2 day =
VAR _currentTime = MAX('Table 2'[Time])
VAR _today = DATE(YEAR(MAX('Table'[Date\Time])), MONTH(MAX('Table'[Date\Time])), DAY(MAX('Table'[Date\Time])))
VAR _previousday = CALCULATE(
MAX('Table'[Date\Time].[Date]),
FILTER(
ALL('Table'),
DATE(YEAR('Table'[Date\Time]), MONTH('Table'[Date\Time]), DAY('Table'[Date\Time])) < _today
)
)
VAR _last2day = CALCULATE(
MAX('Table'[Date\Time].[Date]),
FILTER(
ALL('Table'),
DATE(YEAR('Table'[Date\Time]), MONTH('Table'[Date\Time]), DAY('Table'[Date\Time])) < _previousday
)
)
RETURN
CALCULATE(
SUM('Table'[Values]),
FILTER(
ALL('Table'),
TIME(
HOUR('Table'[Date\Time]),
MINUTE('Table'[Date\Time]),
SECOND('Table'[Date\Time])
) = _currentTime && DATE(YEAR('Table'[Date\Time]), MONTH('Table'[Date\Time]), DAY('Table'[Date\Time])) = _last2day
)
)
Last 3 day =
VAR _currentTime = MAX('Table 2'[Time])
VAR _today = DATE(YEAR(MAX('Table'[Date\Time])), MONTH(MAX('Table'[Date\Time])), DAY(MAX('Table'[Date\Time])))
VAR _previousday = CALCULATE(
MAX('Table'[Date\Time].[Date]),
FILTER(
ALL('Table'),
DATE(YEAR('Table'[Date\Time]), MONTH('Table'[Date\Time]), DAY('Table'[Date\Time])) < _today
)
)
VAR _last2day = CALCULATE(
MAX('Table'[Date\Time].[Date]),
FILTER(
ALL('Table'),
DATE(YEAR('Table'[Date\Time]), MONTH('Table'[Date\Time]), DAY('Table'[Date\Time])) < _previousday
)
)
VAR _last3day = CALCULATE(
MAX('Table'[Date\Time].[Date]),
FILTER(
ALL('Table'),
DATE(YEAR('Table'[Date\Time]), MONTH('Table'[Date\Time]), DAY('Table'[Date\Time])) < _last2day
)
)
RETURN
CALCULATE(
SUM('Table'[Values]),
FILTER(
ALL('Table'),
TIME(
HOUR('Table'[Date\Time]),
MINUTE('Table'[Date\Time]),
SECOND('Table'[Date\Time])
) = _currentTime && DATE(YEAR('Table'[Date\Time]), MONTH('Table'[Date\Time]), DAY('Table'[Date\Time])) = _last3day
)
)
AVG =
VAR _Today = IF(
'Table'[Today] <> BLANK(),
1,
0
)
VAR _Previousday = IF(
'Table'[Last day] <> BLANK(),
1,
0
)
VAR _Last2day = IF(
'Table'[Last 2 day] <> BLANK(),
1,
0
)
RETURN
([Last 2 day] + [Last day] + [Today]) / (_Last2day + _Previousday + _Today)
The result is as follow:
Best Regards
Zhengdong Xu
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Hi @yuvan29 ,
Supposing you have a data table like this:
you can try to plot a visual with time column and a measure like this:
Rolling 3d Avg =
VAR _date = SELECTEDVALUE(data[date])
VAR _last3d =
TOPN(
3,
FILTER(ALL(data[Date]), data[date]<_date),
data[date]
)
VAR _3dtotal =
CALCULATE(
SUM(data[value]),
_last3d
)
VAR _result = DIVIDE(_3dtotal, COUNTROWS(_last3d))
RETURN _result
it worked like this:
Please find more info in the attached file.
p.s.:
1. If more info could be provided, the code could be further simplified, like in the attachment.
2. With dedicated calendar tables, you will also find Time Intelligence functions like DATESINPERIOD very handy for such cases.
Hi @yuvan29 ,
Supposing you have a data table like this:
you can try to plot a visual with time column and a measure like this:
Rolling 3d Avg =
VAR _date = SELECTEDVALUE(data[date])
VAR _last3d =
TOPN(
3,
FILTER(ALL(data[Date]), data[date]<_date),
data[date]
)
VAR _3dtotal =
CALCULATE(
SUM(data[value]),
_last3d
)
VAR _result = DIVIDE(_3dtotal, COUNTROWS(_last3d))
RETURN _result
it worked like this:
Please find more info in the attached file.
p.s.:
1. If more info could be provided, the code could be further simplified, like in the attachment.
2. With dedicated calendar tables, you will also find Time Intelligence functions like DATESINPERIOD very handy for such cases.
New Measure
Average Calls Last 3 Days =
VAR SelectedTime = SELECTEDVALUE('YourTable'[Time])
VAR SelectedDate = SELECTEDVALUE('YourTable'[Date])
RETURN
AVERAGEX(
DATESINPERIOD(
'YourTable'[Date],
SelectedDate,
-3,
DAY
),
CALCULATE(
SUM('YourTable'[NumberOfCalls]),
'YourTable'[Time] = SelectedTime
)
)
Add a Line Chart
Put your Time on the X-axis.
Use the measure Average Calls Last 3 Days for the Y-axis.
💌 If this helped, a Kudos 👍 or Solution mark would be great! 🎉
Cheers,
Kedar
Connect on LinkedIn
Hi @yuvan29
Measure can only return one value at a date point, so I create 4 measures.
Here's the sample:
Table:
Last day =
VAR _currentTime = MAX('Table 2'[Time])
VAR _today = DATE(YEAR(MAX('Table'[Date\Time])), MONTH(MAX('Table'[Date\Time])), DAY(MAX('Table'[Date\Time])))
VAR _previousday = CALCULATE(
MAX('Table'[Date\Time].[Date]),
FILTER(
ALL('Table'),
DATE(YEAR('Table'[Date\Time]), MONTH('Table'[Date\Time]), DAY('Table'[Date\Time])) < _today
)
)
RETURN
CALCULATE(
SUM('Table'[Values]),
FILTER(
ALL('Table'),
TIME(
HOUR('Table'[Date\Time]),
MINUTE('Table'[Date\Time]),
SECOND('Table'[Date\Time])
) = _currentTime && DATE(YEAR('Table'[Date\Time]), MONTH('Table'[Date\Time]), DAY('Table'[Date\Time])) = _previousday
)
)
Last 2 day =
VAR _currentTime = MAX('Table 2'[Time])
VAR _today = DATE(YEAR(MAX('Table'[Date\Time])), MONTH(MAX('Table'[Date\Time])), DAY(MAX('Table'[Date\Time])))
VAR _previousday = CALCULATE(
MAX('Table'[Date\Time].[Date]),
FILTER(
ALL('Table'),
DATE(YEAR('Table'[Date\Time]), MONTH('Table'[Date\Time]), DAY('Table'[Date\Time])) < _today
)
)
VAR _last2day = CALCULATE(
MAX('Table'[Date\Time].[Date]),
FILTER(
ALL('Table'),
DATE(YEAR('Table'[Date\Time]), MONTH('Table'[Date\Time]), DAY('Table'[Date\Time])) < _previousday
)
)
RETURN
CALCULATE(
SUM('Table'[Values]),
FILTER(
ALL('Table'),
TIME(
HOUR('Table'[Date\Time]),
MINUTE('Table'[Date\Time]),
SECOND('Table'[Date\Time])
) = _currentTime && DATE(YEAR('Table'[Date\Time]), MONTH('Table'[Date\Time]), DAY('Table'[Date\Time])) = _last2day
)
)
Last 3 day =
VAR _currentTime = MAX('Table 2'[Time])
VAR _today = DATE(YEAR(MAX('Table'[Date\Time])), MONTH(MAX('Table'[Date\Time])), DAY(MAX('Table'[Date\Time])))
VAR _previousday = CALCULATE(
MAX('Table'[Date\Time].[Date]),
FILTER(
ALL('Table'),
DATE(YEAR('Table'[Date\Time]), MONTH('Table'[Date\Time]), DAY('Table'[Date\Time])) < _today
)
)
VAR _last2day = CALCULATE(
MAX('Table'[Date\Time].[Date]),
FILTER(
ALL('Table'),
DATE(YEAR('Table'[Date\Time]), MONTH('Table'[Date\Time]), DAY('Table'[Date\Time])) < _previousday
)
)
VAR _last3day = CALCULATE(
MAX('Table'[Date\Time].[Date]),
FILTER(
ALL('Table'),
DATE(YEAR('Table'[Date\Time]), MONTH('Table'[Date\Time]), DAY('Table'[Date\Time])) < _last2day
)
)
RETURN
CALCULATE(
SUM('Table'[Values]),
FILTER(
ALL('Table'),
TIME(
HOUR('Table'[Date\Time]),
MINUTE('Table'[Date\Time]),
SECOND('Table'[Date\Time])
) = _currentTime && DATE(YEAR('Table'[Date\Time]), MONTH('Table'[Date\Time]), DAY('Table'[Date\Time])) = _last3day
)
)
AVG =
VAR _Today = IF(
'Table'[Today] <> BLANK(),
1,
0
)
VAR _Previousday = IF(
'Table'[Last day] <> BLANK(),
1,
0
)
VAR _Last2day = IF(
'Table'[Last 2 day] <> BLANK(),
1,
0
)
RETURN
([Last 2 day] + [Last day] + [Today]) / (_Last2day + _Previousday + _Today)
The result is as follow:
Best Regards
Zhengdong Xu
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Prices go up Feb. 11th.
Check out the January 2025 Power BI update to learn about new features in Reporting, Modeling, and Data Connectivity.
User | Count |
---|---|
21 | |
15 | |
14 | |
11 | |
7 |
User | Count |
---|---|
25 | |
24 | |
12 | |
12 | |
11 |