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

Enhance your career with this limited time 50% discount on Fabric and Power BI exams. Ends August 31st. Request your voucher.

Reply
rpiboy_1
Helper V
Helper V

Summarize a table in 'Add Column'

I have a data model:

  • Dimension Table: Project Name, Project.ID
  • Fact Table: Project.ID, Date, IsActive

 

[IsActive] is a true false column and indicates if the Project was active on the given date.

 

I want to summarize IsActive into the Dimension Table as a new Column, such that

Project has Activity = IF( IsActive IN {True()}, TRUE(), FALSE() )

 

In plain English, if the Project has ever been Active then it will be marked as Active (true), if there has never been any Activity, then the Project is 'Not Active' (false). The reason for doing this as a column is I want to be able to use the value as a Slicer and you can't put measures in Slicers, and if you put the Dimension column in a slicer, I'd have to enable bi-directional filtering on the relationship between the the Fact and Dimension tables.

I'm struggling with writing the DAX expression that gets me to the IsActive column so that I can evaulate it in my IF statement. I can 'get' the table using RELATEDTABLE() but I'm having a brain freeze on how to then navigate my variable to get to the column, since RELATEDTABLE does not accept a column arguement with the table name.

Thoughts, suggestions, should I approach this differently?

1 ACCEPTED SOLUTION
rpiboy_1
Helper V
Helper V

Well thanks everyone, you gave me something to chew on at least.

 @Jihwan_Kim you raised the point loosing any dynamic changes related to date. That is exactly the point. In this case I'm not concerned about date, only if the Project has ever been Active or Not. I have the Fact table at my disposal if its important to drill into granular monthly behavior.

@Anonymous your solution works assuming that a given project only has one entry in the Fact Table, or for each entry the value is the same. But it did get me thinking, which was helpful!

In the end my solution looks like this, if the calculated table is empty, then I know there are no 'true' values indicating the project has had some activity at some point in time. Therefore we can safely assume that the project has never been active and use ISEMPTY to retern the appropriate boolean value.

No Activity = 
VAR _projactivedays = 
    CALCULATETABLE(
        'Project Active Days Monthly',
        KEEPFILTERS('Project Active Days Monthly'[IsActive] = TRUE())
    )
VAR _activecolumn = ISEMPTY(_projactivedays)
VAR _result = IF( _activecolumn, TRUE(), FALSE() )
RETURN
    _result

View solution in original post

3 REPLIES 3
rpiboy_1
Helper V
Helper V

Well thanks everyone, you gave me something to chew on at least.

 @Jihwan_Kim you raised the point loosing any dynamic changes related to date. That is exactly the point. In this case I'm not concerned about date, only if the Project has ever been Active or Not. I have the Fact table at my disposal if its important to drill into granular monthly behavior.

@Anonymous your solution works assuming that a given project only has one entry in the Fact Table, or for each entry the value is the same. But it did get me thinking, which was helpful!

In the end my solution looks like this, if the calculated table is empty, then I know there are no 'true' values indicating the project has had some activity at some point in time. Therefore we can safely assume that the project has never been active and use ISEMPTY to retern the appropriate boolean value.

No Activity = 
VAR _projactivedays = 
    CALCULATETABLE(
        'Project Active Days Monthly',
        KEEPFILTERS('Project Active Days Monthly'[IsActive] = TRUE())
    )
VAR _activecolumn = ISEMPTY(_projactivedays)
VAR _result = IF( _activecolumn, TRUE(), FALSE() )
RETURN
    _result
Jihwan_Kim
Super User
Super User

Hi,

I am not sure how your semantic model looks like, but I suggest to try creating field parameters.

In this case, measures can be in the slicer and it can dynamically show the result by changing the date slicer as well.

In my opinion, if you create calculated column, it will not be dynamically showing the result as date slicer changes.

 

Please check the below picture and the attached pbix file.

 

 

Jihwan_Kim_0-1715138388260.png

 

You can refere to the below link to find out how to create Field parameters

Let report readers use field parameters to change visuals (preview) - Power BI | Microsoft Learn

 

 

Is Active measure: = 
VAR _t =
    FILTER (
        RELATEDTABLE ( project_active_fact ),
        MAX(project_active_fact[is_active]) = 1
    )
RETURN
    IF ( COUNTROWS ( _t ) > 0, "Is Active" )

 

 

 

Is Inactive measure: = 
VAR _t =
    FILTER (
        RELATEDTABLE ( project_active_fact ),
        MAX(project_active_fact[is_active]) = 0
    )
RETURN
    IF ( COUNTROWS ( _t ) > 0, "Is Inactive" )

 

 


If this post helps, then please consider accepting it as the solution to help other members find it faster, and give a big thumbs up.


Click here to visit my LinkedIn page

Click here to schedule a short Teams meeting to discuss your question.
Anonymous
Not applicable

Hi @rpiboy_1 ,
Here some steps that I want to share, you can check them if they suitable for your requirement.
Here is my test data:
Relationship

vheqmsft_3-1715137026635.png

 


Demention Table

vheqmsft_0-1715136921439.png
Fact Table

vheqmsft_1-1715136944817.png

Create a column in Demention Table

Project has Activity = 
CALCULATE(
    MAXX(
        RELATEDTABLE('Fact Table'),
        IF('Fact Table'[IsActive] = TRUE(), 1, 0)
    )
) > 0

Final output

vheqmsft_2-1715136994136.png

 

Best regards,
Albert He

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

Helpful resources

Announcements
July PBI25 Carousel

Power BI Monthly Update - July 2025

Check out the July 2025 Power BI update to learn about new features.

Join our Fabric User Panel

Join our Fabric User Panel

This is your chance to engage directly with the engineering team behind Fabric and Power BI. Share your experiences and shape the future.

June 2025 community update carousel

Fabric Community Update - June 2025

Find out what's new and trending in the Fabric community.