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

Find everything you need to get certified on Fabric—skills challenges, live sessions, exam prep, role guidance, and more. Get started

Reply
Anonymous
Not applicable

how to use SWITCH in a filter expression in CALCULATE

I have a measure whose filters need to change depending on a selection from a disconnected table ('Peer Set Options').  A user selects an employee.  When 'Peer Set Options'[Option] = "all", no additional filter should be applied; when 'Peer Set Options'[Option] = "group", the measure should be additionally filtered to all people in the selected employee's group.  I have tried using SWITCH for this behavior, but it's throwing the following error:

 

The True/False expression does not specify a column.  Each True/False expressions used as a table filter expression must refer to exactly one column.

 

How can I resolve this?

 

My measure is:

Total Hours - Peer Set =
VAR __peer_set_option =
SELECTEDVALUE(

    'Disconnected Table'[Option]

    ,BLANK()

)

VAR __Groups =
DISTINCT(
    SELECTCOLUMNS(
        ALLSELECTED('Dimension Employee')
        ,"Group"
        ,'Dimension Employee'[Group]

    )
)

 

RETURN

    CALCULATE(

        SUM('Fact Time Worked'[Hours])
        ,ALL('Dimension Employee') //clear the filter context created by the employee selection

        ,SWITCH(

            __peer_set_option

            ,"all", TRUE

            ,"group", __Groups

        )
    )

 

2 ACCEPTED SOLUTIONS
CNENFRNL
Community Champion
Community Champion

Hi, @Anonymous , you might want to author the measure this way,

Total Hours - Peer Set =
VAR __peer_set_option =
    SELECTEDVALUE ( 'Disconnected Table'[Option] ) //it defaults to BLANK() if the 2nd parameter is omitted
VAR __Groups =
    DISTINCT (
        SELECTCOLUMNS (
            ALLSELECTED ( 'Dimension Employee' ),
            "Group", 'Dimension Employee'[Group]
        )
    )
RETURN
    SWITCH (
        __peer_set_option,
        "all", CALCULATE ( SUM ( 'Fact Time Worked'[Hours] ), ALL ( 'Dimension Employee' ) ),
        "group",
            CALCULATE (
                SUM ( 'Fact Time Worked'[Hours] ),
                ALL ( 'Dimension Employee' ),
                __Groups
            ),
        "Some other calculation when __peer_set_option evaluates to BLANK()"
    )

Thanks to the great efforts by MS engineers to simplify syntax of DAX! Most beginners are SUCCESSFULLY MISLED to think that they could easily master DAX; but it turns out that the intricacy of the most frequently used RANKX() is still way beyond their comprehension!

DAX is simple, but NOT EASY!

View solution in original post

v-rzhou-msft
Community Support
Community Support

Hi @Anonymous 

Due to I don't know your data model and values, I build a sample for you.

My sample table:

1.png

Group Table:

2.png

Build a people table as well.

People = VALUES('Fact Time Worked'[People]) 

Measure:

M.Hour = 
VAR _Group = SELECTEDVALUE('Group'[Group])
VAR _People = SELECTEDVALUE(People[People])
Return
SWITCH(TRUE(),
_Group = "ALL",SUM('Fact Time Worked'[Hours]),
_Group=BLANK(),SUMX(FILTER('Fact Time Worked','Fact Time Worked'[People]=_People),'Fact Time Worked'[Hours]),
SUMX(FILTER('Fact Time Worked','Fact Time Worked'[Group]=_Group&&'Fact Time Worked'[People]=_People),'Fact Time Worked'[Hours]))

Result is as below.

Only select "A" in People:

3.png

Select "All"  in Group and then select "A" in People:

4.png

Select "G1" in Group and Select “A" in People:

5.png

You can download the pbix file from this link: how to use SWITCH in a filter expression in CALCULATE

If this reply still couldn't help you solve your problem, please provide me a sample data like yours. And show me the result you want.(A screenshot may be better)

This may make it easier for me to understand your requirement and your calcualte logic.

 

Best Regards,

Rico Zhou

 

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-rzhou-msft
Community Support
Community Support

Hi @Anonymous 

Could you tell me if your problem has been solved? If it is, kindly Accept it as the solution. More people will benefit from it. Or you are still confused about it, please provide me with more details about your table and your problem or share me with your pbix file from your Onedrive for Business.

 

Best Regards,

Rico Zhou

v-rzhou-msft
Community Support
Community Support

Hi @Anonymous 

Due to I don't know your data model and values, I build a sample for you.

My sample table:

1.png

Group Table:

2.png

Build a people table as well.

People = VALUES('Fact Time Worked'[People]) 

Measure:

M.Hour = 
VAR _Group = SELECTEDVALUE('Group'[Group])
VAR _People = SELECTEDVALUE(People[People])
Return
SWITCH(TRUE(),
_Group = "ALL",SUM('Fact Time Worked'[Hours]),
_Group=BLANK(),SUMX(FILTER('Fact Time Worked','Fact Time Worked'[People]=_People),'Fact Time Worked'[Hours]),
SUMX(FILTER('Fact Time Worked','Fact Time Worked'[Group]=_Group&&'Fact Time Worked'[People]=_People),'Fact Time Worked'[Hours]))

Result is as below.

Only select "A" in People:

3.png

Select "All"  in Group and then select "A" in People:

4.png

Select "G1" in Group and Select “A" in People:

5.png

You can download the pbix file from this link: how to use SWITCH in a filter expression in CALCULATE

If this reply still couldn't help you solve your problem, please provide me a sample data like yours. And show me the result you want.(A screenshot may be better)

This may make it easier for me to understand your requirement and your calcualte logic.

 

Best Regards,

Rico Zhou

 

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

CNENFRNL
Community Champion
Community Champion

Hi, @Anonymous , you might want to author the measure this way,

Total Hours - Peer Set =
VAR __peer_set_option =
    SELECTEDVALUE ( 'Disconnected Table'[Option] ) //it defaults to BLANK() if the 2nd parameter is omitted
VAR __Groups =
    DISTINCT (
        SELECTCOLUMNS (
            ALLSELECTED ( 'Dimension Employee' ),
            "Group", 'Dimension Employee'[Group]
        )
    )
RETURN
    SWITCH (
        __peer_set_option,
        "all", CALCULATE ( SUM ( 'Fact Time Worked'[Hours] ), ALL ( 'Dimension Employee' ) ),
        "group",
            CALCULATE (
                SUM ( 'Fact Time Worked'[Hours] ),
                ALL ( 'Dimension Employee' ),
                __Groups
            ),
        "Some other calculation when __peer_set_option evaluates to BLANK()"
    )

Thanks to the great efforts by MS engineers to simplify syntax of DAX! Most beginners are SUCCESSFULLY MISLED to think that they could easily master DAX; but it turns out that the intricacy of the most frequently used RANKX() is still way beyond their comprehension!

DAX is simple, but NOT EASY!

Helpful resources

Announcements
Europe Fabric Conference

Europe’s largest Microsoft Fabric Community Conference

Join the community in Stockholm for expert Microsoft Fabric learning including a very exciting keynote from Arun Ulag, Corporate Vice President, Azure Data.

Power BI Carousel June 2024

Power BI Monthly Update - June 2024

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

RTI Forums Carousel3

New forum boards available in Real-Time Intelligence.

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