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
Hi All,
I have a date table and fact table which are connected to each other via one-to-many.
I'm using the following dax to get the out put:
Solved! Go to Solution.
Hi @Anonymous ,
Due to I don't know your data model, I will share a workaround by my sample.
Tables:
Date = ADDCOLUMNS(CALENDARAUTO(),"Year",YEAR([Date]),"Month",MONTH([Date]),"WeekDay",WEEKDAY([Date],2))
Measure:
#Days_Den =
VAR _d = DATEDIFF(MAX('Table'[ExpectedStartDate]), MAX('Table'[ExpectedEndDate]), SECOND)
VAR _min = DIVIDE(_d,60)
VAR _hour = DIVIDE(_min,60)
VAR _day = DIVIDE(_hour,24)
VAR _weekend = CALCULATE(COUNT('Date'[Date]),FILTER('Date','Date'[WeekDay] in {6,7} && 'Date'[Date]>=MAX('Table'[ExpectedStartDate]) && 'Date'[Date]<= MAX('Table'[ExpectedEndDate])))
return
_day - _weekend
Result is as below.
Best Regards,
Rico Zhou
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Hi @Anonymous ,
Due to I don't know your data model, I will share a workaround by my sample.
Tables:
Date = ADDCOLUMNS(CALENDARAUTO(),"Year",YEAR([Date]),"Month",MONTH([Date]),"WeekDay",WEEKDAY([Date],2))
Measure:
#Days_Den =
VAR _d = DATEDIFF(MAX('Table'[ExpectedStartDate]), MAX('Table'[ExpectedEndDate]), SECOND)
VAR _min = DIVIDE(_d,60)
VAR _hour = DIVIDE(_min,60)
VAR _day = DIVIDE(_hour,24)
VAR _weekend = CALCULATE(COUNT('Date'[Date]),FILTER('Date','Date'[WeekDay] in {6,7} && 'Date'[Date]>=MAX('Table'[ExpectedStartDate]) && 'Date'[Date]<= MAX('Table'[ExpectedEndDate])))
return
_day - _weekend
Result is as below.
Best Regards,
Rico Zhou
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now!
| User | Count |
|---|---|
| 39 | |
| 38 | |
| 38 | |
| 28 | |
| 25 |
| User | Count |
|---|---|
| 124 | |
| 87 | |
| 70 | |
| 66 | |
| 65 |