Power BI is turning 10! Tune in for a special live episode on July 24 with behind-the-scenes stories, product evolution highlights, and a sneak peek at what’s in store for the future.
Save the dateJoin us for an expert-led overview of the tools and concepts you'll need to become a Certified Power BI Data Analyst and pass exam PL-300. Register now.
Hi all,
I have a fact table that has start and end dates for a process. My goal is to create a calculated column in that fact table to determine the number of days in that period that were holidays.
Separately, I have a dim date table that has a column to denote whether a given date is a holiday or not.
What I thought I'd be able to do is use something along the lines of
=COUNTROWS(
CALCULATETABLE(
DATESBETWEEN(
'Date Table'[Dates], 'Fact Table'[Start Date], 'Fact Table'[End Date]),
'Date Table'[IsHoliday?] = TRUE
)
)
The issue I'm running into is the DATESBETWEEN function won't accept values from the Fact Table. The relationship between the two tables is defined in the model.
Any thoughts on why this isn't working or a better approach?
Solved! Go to Solution.
@VasTg wrote:How is the relationship between the fact and date is defined?
It is a one-to-many relationship between the date from the date table to the start date in the fact table.
@VasTg wrote:Here is the sample DAX that works for me.
Column = CALCULATE(SUM('Table 2'[Holiday]),FILTER(ALL('Table 2'),'Table 2'[Date]>='Fact'[Start] &&'Table 2'[Date]<='Fact'[End]))
This did not work for me either as DAX is not allowing my to compare the dates from the Fact table to the Date table, I suspect for the same reason as I'm not able to use the functions I intended to.
How is the relationship between the fact and date is defined?
Here is the sample DAX that works for me.
Column = CALCULATE(SUM('Table 2'[Holiday]),FILTER(ALL('Table 2'),'Table 2'[Date]>='Fact'[Start] &&'Table 2'[Date]<='Fact'[End]))
Table 2 is date(Holiday is a column with value 1 as holiday and 0 is a non holiday)
Fact is your fact.
If this helps, mark it as a solution
Kudos are nice too
I was able to get your formula to work with a bit of modification:
Holidays in Period =
CALCULATE(
SUM('Date Table'[IsHoliday]),
FILTER('Date Table',
'Date Table'[FullDate] >='Fact Table'[Start Date]
&& 'Date Table'[FullDate] <= 'Fact Table'[End Date]
)
)
@VasTg wrote:How is the relationship between the fact and date is defined?
It is a one-to-many relationship between the date from the date table to the start date in the fact table.
@VasTg wrote:Here is the sample DAX that works for me.
Column = CALCULATE(SUM('Table 2'[Holiday]),FILTER(ALL('Table 2'),'Table 2'[Date]>='Fact'[Start] &&'Table 2'[Date]<='Fact'[End]))
This did not work for me either as DAX is not allowing my to compare the dates from the Fact table to the Date table, I suspect for the same reason as I'm not able to use the functions I intended to.
Check out the July 2025 Power BI update to learn about new features.
This is your chance to engage directly with the engineering team behind Fabric and Power BI. Share your experiences and shape the future.
User | Count |
---|---|
16 | |
9 | |
7 | |
7 | |
6 |
User | Count |
---|---|
23 | |
11 | |
10 | |
10 | |
8 |