Skip to main content
cancel
Showing results for 
Search instead for 
Did you mean: 

Grow your Fabric skills and prepare for the DP-600 certification exam by completing the latest Microsoft Fabric challenge.

Reply
ClemFandango
Helper II
Helper II

Count column value based on multiple criteria in another table

Hi all,

 

I am hoping someone can help. I am trying to count the number of 'ID' in table 1 where the 'Date' is >= 'Start' & <= 'End' (from Table 2). I have tried the DAX below, but this appears to just count all rows (instead of ID) found between the 'Start' & 'End' date.

 

 

 

 Count = CALCULATE (
    DISTINCTCOUNT ( 'Table2'[ID] ),
    FILTER ('Table2',
       [Date] >= 'Table2'[Start Date]
            && [Date] <= 'Table2'[End Date]
              && Table2[ID] = [ID]
                       ))

 

 

 

 

I am attempting to generate the results shown in the 'Count' column below.

Table1

IDDateCount
104/01/24  2
230/01/24  1
330/01/24  0
410/01/24  1

 

Table2

IDStartEnd
101/01/24  01/01/25
105/01/24  05/01/25
104/01/24  04/01/24
201/01/22  01/01/23
212/12/23  05/05/24
301/01/20  01/01/21
401/01/24  10/01/24

 

Any help eternally appreciated!

 

CM

2 ACCEPTED SOLUTIONS
selimovd
Super User
Super User

Hey @ClemFandango ,

 

as I understand, you want the result as calculated column, is that right?
Try the following calculated column:

Count = 
VAR _DateCurrentRow = Table1[Date]
VAR _IDCurrentRow = Table1[ID]
VAR _FilterTable2 = FILTER( Table2, [Start] <= _DateCurrentRow && [End] >= _DateCurrentRow && Table2[ID] = _IDCurrentRow)
VAR _Result = COUNTROWS( _FilterTable2 )
RETURN
_Result

 

If you need any help please let me know.
If I answered your question I would be happy if you could mark my post as a solution ✔️ and give it a thumbs up 👍

Best regards
Denis

Blog: WhatTheFact.bi
Follow me: twitter.com/DenSelimovic

View solution in original post

v-yohua-msft
Community Support
Community Support

Hi, @ClemFandango 


Maybe you can use the follow DAX :

 

vyohuamsft_0-1708497632317.png

 

Count = 
VAR _count=CALCULATE (
    COUNT ( 'Table2'[ID] ),
    FILTER ('Table2',
       RELATED(Table1[Date]) >= 'Table2'[Start]
            && RELATED(Table1[Date]) <= 'Table2'[End]
              && Table2[ID] = [ID]
                       ))
RETURN
IF(_count> 0,
_count,
 0)

 

Here is my preview:

 

vyohuamsft_1-1708497692721.png

 

 

How to Get Your Question Answered Quickly 

If it does not help, please provide more details with your desired output and pbix file without privacy information (or some sample data)

Best Regards

Yongkang Hua

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

View solution in original post

3 REPLIES 3
v-yohua-msft
Community Support
Community Support

Hi, @ClemFandango 


Maybe you can use the follow DAX :

 

vyohuamsft_0-1708497632317.png

 

Count = 
VAR _count=CALCULATE (
    COUNT ( 'Table2'[ID] ),
    FILTER ('Table2',
       RELATED(Table1[Date]) >= 'Table2'[Start]
            && RELATED(Table1[Date]) <= 'Table2'[End]
              && Table2[ID] = [ID]
                       ))
RETURN
IF(_count> 0,
_count,
 0)

 

Here is my preview:

 

vyohuamsft_1-1708497692721.png

 

 

How to Get Your Question Answered Quickly 

If it does not help, please provide more details with your desired output and pbix file without privacy information (or some sample data)

Best Regards

Yongkang Hua

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

selimovd
Super User
Super User

Hey @ClemFandango ,

 

as I understand, you want the result as calculated column, is that right?
Try the following calculated column:

Count = 
VAR _DateCurrentRow = Table1[Date]
VAR _IDCurrentRow = Table1[ID]
VAR _FilterTable2 = FILTER( Table2, [Start] <= _DateCurrentRow && [End] >= _DateCurrentRow && Table2[ID] = _IDCurrentRow)
VAR _Result = COUNTROWS( _FilterTable2 )
RETURN
_Result

 

If you need any help please let me know.
If I answered your question I would be happy if you could mark my post as a solution ✔️ and give it a thumbs up 👍

Best regards
Denis

Blog: WhatTheFact.bi
Follow me: twitter.com/DenSelimovic

This is amazing - thanks so much

Helpful resources

Announcements
RTI Forums Carousel3

New forum boards available in Real-Time Intelligence.

Ask questions in Eventhouse and KQL, Eventstream, and Reflex.

MayPowerBICarousel

Power BI Monthly Update - May 2024

Check out the May 2024 Power BI update to learn about new features.