Find everything you need to get certified on Fabric—skills challenges, live sessions, exam prep, role guidance, and more. Get started
Visitor ID | Date | Visit |
1 | 5/10/2022 | Visit 1 |
2 | 5/10/2022 | Visit 1 |
3 | 5/10/2022 | Visit 1 |
1 | 5/10/2022 | Visit 2 |
5 | 5/10/2022 | Visit 1 |
2 | 5/10/2022 | Visit 2 |
1 | 5/11/2022 | Visit 1 |
6 | 5/11/2022 | Visit 1 |
9 | 5/11/2022 | Visit 1 |
10 | 5/12/2022 | Visit 1 |
11 | 5/12/2022 | Visit 1 |
12 | 5/13/2022 | Visit 1 |
2 | 5/16/2022 | Visit 1 |
2 | 5/16/2022 | Visit 2 |
13 | 5/18/2022 | Visit 1 |
14 | 5/18/2022 | Visit 1 |
Hello everyone,
I'm trying to calculate average weekly active visitors in PowerBI using DAX based on the example in the table above.
First, I need to calculate how many unique visitors visit the shop in one week (Mon-Sun). Based on the calendar, 5/10/2022 - 5/13/2022 will be categorized under one week, and 5/16/2022 - 5/18/2022 is another week. So for the week from 5/10/2022 - 5/13/2022, there are 9 unique visitor and for the week from 5/16/2022 - 5/18/2022, there are 3 unique visitors.
Once I found out the unique visitor for respective weeks, then I can get the average weekly active visitor by:
(9+3)/2 = 6 visitors
Hence, the answer for the example in the screenshot will be 6 visitors. The output will be used in card visualization.
Struggling to find the best way to do this, any help or advise will be greatly appreciated!
*Take note that Visit 1 means the first visit of the day while Visit 2 means the 2nd visit for the day.
Solved! Go to Solution.
Hi,
Thank you for your feedback.
What i meant was, consider to insert one more condition that limits same-year-number into the measure.
It depends on how you define year number and week number.
Is it depends on ISO week number?
What happens if year changes during the week?
Just for simplifying the situation, I amended the measure a little bit.
Please check the below amended measure.
Based on your decision on how you define year number and week number, especially on the last week of the year or the first week of the year, the below measure has to be resived a little bit.
But I think the below measure will work rest of the weeks during the year.
I also fixed the measure in the attached pbix file.
Expected outcome measure: =
VAR currentyearnumber =
YEAR ( TODAY () )
VAR week_column =
FILTER (
SUMMARIZE (
ADDCOLUMNS (
Data,
"@weeknumber", WEEKNUM ( Data[Date], 21 ),
"@yearnumber", YEAR ( Data[Date] )
),
Data[Visitor ID],
[@weeknumber],
[@yearnumber]
),
[@yearnumber] = currentyearnumber
)
VAR countID =
GROUPBY (
week_column,
[@weeknumber],
[@yearnumber],
"@count", SUMX ( CURRENTGROUP (), 1 )
)
RETURN
AVERAGEX ( countID, [@count] )
If this post helps, then please consider accepting it as the solution to help other members find it faster, and give a big thumbs up.
Thanks for your solution! As you mentioned, by using WEEKNUM, it will cause a problem if I have data for May 2023. Do you mean replace WEEKNUM by something else?
Hi,
Thank you for your feedback.
What i meant was, consider to insert one more condition that limits same-year-number into the measure.
It depends on how you define year number and week number.
Is it depends on ISO week number?
What happens if year changes during the week?
Just for simplifying the situation, I amended the measure a little bit.
Please check the below amended measure.
Based on your decision on how you define year number and week number, especially on the last week of the year or the first week of the year, the below measure has to be resived a little bit.
But I think the below measure will work rest of the weeks during the year.
I also fixed the measure in the attached pbix file.
Expected outcome measure: =
VAR currentyearnumber =
YEAR ( TODAY () )
VAR week_column =
FILTER (
SUMMARIZE (
ADDCOLUMNS (
Data,
"@weeknumber", WEEKNUM ( Data[Date], 21 ),
"@yearnumber", YEAR ( Data[Date] )
),
Data[Visitor ID],
[@weeknumber],
[@yearnumber]
),
[@yearnumber] = currentyearnumber
)
VAR countID =
GROUPBY (
week_column,
[@weeknumber],
[@yearnumber],
"@count", SUMX ( CURRENTGROUP (), 1 )
)
RETURN
AVERAGEX ( countID, [@count] )
If this post helps, then please consider accepting it as the solution to help other members find it faster, and give a big thumbs up.
Thanks for your edited answer! I think the latest measure solved my concern.
Hi,
Please check the below measure and the attached pbix file.
Please be noted that if your real data is showing not just one year, the year number calculation also has to be considered in the measure.
Expected outcome measure: =
VAR week_column =
SUMMARIZE (
ADDCOLUMNS ( Data, "@weeknumber", WEEKNUM ( Data[Date], 21) ),
Data[Visitor ID],
[@weeknumber]
)
VAR countID =
GROUPBY ( week_column, [@weeknumber], "@count", SUMX ( CURRENTGROUP (), 1 ) )
RETURN
AVERAGEX ( countID, [@count] )
If this post helps, then please consider accepting it as the solution to help other members find it faster, and give a big thumbs up.
Check out the September 2024 Power BI update to learn about new features.
Learn from experts, get hands-on experience, and win awesome prizes.
User | Count |
---|---|
25 | |
20 | |
18 | |
18 | |
15 |
User | Count |
---|---|
38 | |
20 | |
19 | |
16 | |
10 |