cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
Helper I
Helper I

Filtering the dates in one table by the dates in another table

Good afternoon,

 

I have two separate tables in a .pbix file. The first, TABLE A, has a column of dates from 2016-01-01 to 2022-12-31 (it is complete list with 1,828 rows). The second, TABLE B, has a shorter column of dates listing the dates for New Years Day, Labor Day and Thanksgiving for 2016 to 2022. I want to create a column in TABLE A that is "yes" if the date appears in both TABLE A and TABLE B, and "no" if the date only appears in TABLE A. 

 

I've tried looking for help how to do this, and am lost. Is there a way to do this with DAX in Power BI?

 

Thank you in advance for your help. 

1 ACCEPTED SOLUTION
Super User III
Super User III

If your Date table (many rows) is related with  1 to many relationship with the Holiday table (table b) you can use this calculated column:

 

 

Holiday =
IF(
    COUNTROWS(
        RELATEDTABLE( Holiday )
    ) = 0,
    "No",
    "Yes"
)

 

It simply counts the rows in the related Holiday table that have the same date as the date table. 

However, calculated columns are generally a bad practice. Can you back this up into Power Query? 

 

In general, try to avoid calculated columns. There are times to use them, but it is rare. Getting data out of the source system, creating columns in Power Query, or DAX Measures are usually preferred to calculated columns. See these references:
Calculated Columns vs Measures in DAX
Calculated Columns and Measures in DAX
Storage differences between calculated columns and calculated tables

If you merge the table a with table b (date with holiday) as shown below:

edhans_0-1599168487385.png

Then you could expand the date column from the B table as shown here:

edhans_1-1599168551957.png

I have then added a custom column called IsHoliday with the following formula:

if [Date.1] is null then "No" else "Yes"

Then you remove the unneeded Date.1 column and now you have a clean Date table in your model with no calculated columns.



Did I answer your question? Mark my post as a solution!
Did my answers help arrive at a solution? Give it a kudos by clicking the Thumbs Up!

DAX is for Analysis. Power Query is for Data Modeling


Proud to be a Super User!

MCSA: BI Reporting

View solution in original post

1 REPLY 1
Super User III
Super User III

If your Date table (many rows) is related with  1 to many relationship with the Holiday table (table b) you can use this calculated column:

 

 

Holiday =
IF(
    COUNTROWS(
        RELATEDTABLE( Holiday )
    ) = 0,
    "No",
    "Yes"
)

 

It simply counts the rows in the related Holiday table that have the same date as the date table. 

However, calculated columns are generally a bad practice. Can you back this up into Power Query? 

 

In general, try to avoid calculated columns. There are times to use them, but it is rare. Getting data out of the source system, creating columns in Power Query, or DAX Measures are usually preferred to calculated columns. See these references:
Calculated Columns vs Measures in DAX
Calculated Columns and Measures in DAX
Storage differences between calculated columns and calculated tables

If you merge the table a with table b (date with holiday) as shown below:

edhans_0-1599168487385.png

Then you could expand the date column from the B table as shown here:

edhans_1-1599168551957.png

I have then added a custom column called IsHoliday with the following formula:

if [Date.1] is null then "No" else "Yes"

Then you remove the unneeded Date.1 column and now you have a clean Date table in your model with no calculated columns.



Did I answer your question? Mark my post as a solution!
Did my answers help arrive at a solution? Give it a kudos by clicking the Thumbs Up!

DAX is for Analysis. Power Query is for Data Modeling


Proud to be a Super User!

MCSA: BI Reporting

View solution in original post

Helpful resources

Announcements
secondImage

Congratulations!

We are excited to announce the Power BI Super Users!

Microsoft Ignite

Microsoft Ignite with Arun Ulag

Featured Session Drive Data Culture with Power BI: Vision, Strategy & Roadmap. Register here https://myignite.microsoft.com #MSIgnite #PowerPlatform #Power BI ​

Microsoft Ignite

Microsoft Ignite

Join digitally, March 2–4, 2021 to explore new tech that's ready to implement. Experience the keynote in mixed reality through AltspaceVR!

secondImage

The largest Power BI virtual conference

100+ sessions, 100+ speakers, Product managers, MVPs, and experts. All about Power BI. Attend online or watch the recordings.

Top Solution Authors
Top Kudoed Authors