Power BI is turning 10, and we’re marking the occasion with a special community challenge. Use your creativity to tell a story, uncover trends, or highlight something unexpected.
Get startedJoin 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,
I need help with a DAX measure. I want to perform a COUNT. This COUNT should be filtered by DATESINPERIOD, which is 2022. The challenge is, that the date actually can be in 1 of 2 columns. Lets say Schritt10 or Schritt11 for example. How can i write the dax measure?
I tried some measures but they always end in errors : )
For example:
try no. 1: CountIn2022 = COUNTROWS( FILTER( YourTable, (YEAR(YourTable[Schritt10 ]) = 2022 || YEAR(YourTable[Schritt11]) = 2022)
try no. 2:
CountIn2022 =
VAR Schritt10 =
DATESINPERIOD (
YourTable[Schritt10Abgeschlossen],
DATE ( 2022, 01, 01 ),
1,
YEAR
)
VAR Schritt11 =
DATESINPERIOD (
YourTable[Schritt11Abgeschlossen],
DATE ( 2022, 01, 01 ),
1,
YEAR
)
RETURN
CALCULATE (
COUNT ( YourTable[Id] ),
(
Schritt10=TRUE() || Schritt11=TRUE()
))
I hope someone can help me.
Thank you in advance.
Solved! Go to Solution.
You could consider unpivoting your data to simplify things. This approach won't be performant at large scale, but here is one way to do it.
DIP =
VAR dip =
DATESINPERIOD ( 'Date'[Date], MAX ( 'Date'[Date] ), -1, YEAR )
VAR result =
COUNTROWS (
FILTER ( YourTable, YourTable[Schritt10] IN dip || YourTable[Schritt11] IN dip )
)
RETURN
result
If you have many duplicate rows in YourTable, this should be faster.
DIP2 =
VAR dip =
DATESINPERIOD ( 'Date'[Date], MAX ( 'Date'[Date] ), -1, YEAR )
VAR summarizedates =
SUMMARIZE (
YourTable,
YourTable[Schritt10],
YourTable[Schritt11],
"cCount", COUNT ( YourTable[Schritt10] )
)
VAR result =
SUMX (
FILTER (
summarizedates,
YourTable[Schritt10]
IN dip
|| YourTable[Schritt11] IN dip
),
[cCount]
)
RETURN
result
Pat
You could consider unpivoting your data to simplify things. This approach won't be performant at large scale, but here is one way to do it.
DIP =
VAR dip =
DATESINPERIOD ( 'Date'[Date], MAX ( 'Date'[Date] ), -1, YEAR )
VAR result =
COUNTROWS (
FILTER ( YourTable, YourTable[Schritt10] IN dip || YourTable[Schritt11] IN dip )
)
RETURN
result
If you have many duplicate rows in YourTable, this should be faster.
DIP2 =
VAR dip =
DATESINPERIOD ( 'Date'[Date], MAX ( 'Date'[Date] ), -1, YEAR )
VAR summarizedates =
SUMMARIZE (
YourTable,
YourTable[Schritt10],
YourTable[Schritt11],
"cCount", COUNT ( YourTable[Schritt10] )
)
VAR result =
SUMX (
FILTER (
summarizedates,
YourTable[Schritt10]
IN dip
|| YourTable[Schritt11] IN dip
),
[cCount]
)
RETURN
result
Pat
Thank you ppm1,
the first approach works perfectly!
I didnt know about the IN.
This is your chance to engage directly with the engineering team behind Fabric and Power BI. Share your experiences and shape the future.
Check out the June 2025 Power BI update to learn about new features.
User | Count |
---|---|
10 | |
8 | |
8 | |
8 | |
6 |
User | Count |
---|---|
14 | |
12 | |
11 | |
9 | |
9 |