Join us at FabCon Atlanta from March 16 - 20, 2026, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.
Register now!The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now! Learn more
Solved! Go to Solution.
Try
6 month active =
VAR EndDate =
MAX ( 'Date'[Date] )
VAR StartDate = EndDate - 180
VAR AppLogUsers =
CALCULATETABLE (
DISTINCT ( AppLog[UserID] ),
DATESBETWEEN ( 'Date'[Date], StartDate, EndDate )
)
VAR AllPointUsers =
CALCULATETABLE (
DISTINCT ( AllPoint[UserID] ),
DATESBETWEEN ( 'Date'[Date], StartDate, EndDate )
)
VAR CombinedUsers =
DISTINCT ( UNION ( AppLogUsers, AllPointUsers ) )
VAR Result =
COUNTROWS ( CombinedUsers )
RETURN
Result
Try
6 month active =
VAR EndDate =
MAX ( 'Date'[Date] )
VAR StartDate = EndDate - 180
VAR AppLogUsers =
CALCULATETABLE (
DISTINCT ( AppLog[UserID] ),
DATESBETWEEN ( 'Date'[Date], StartDate, EndDate )
)
VAR AllPointUsers =
CALCULATETABLE (
DISTINCT ( AllPoint[UserID] ),
DATESBETWEEN ( 'Date'[Date], StartDate, EndDate )
)
VAR CombinedUsers =
DISTINCT ( UNION ( AppLogUsers, AllPointUsers ) )
VAR Result =
COUNTROWS ( CombinedUsers )
RETURN
Result
I never thought of using calculate table to transform them into same headers then union.
I still need to get UserId into AppLog table somehow to test this, but your answer already give me the general idea and direction, which I can pretty much see that it will definitely work.
This look much cleaner than my approach too!
Thank you very much for your assistance.
The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now!
| User | Count |
|---|---|
| 66 | |
| 44 | |
| 40 | |
| 29 | |
| 19 |
| User | Count |
|---|---|
| 200 | |
| 126 | |
| 103 | |
| 70 | |
| 54 |