Get certified in Microsoft Fabric—for free! For a limited time, the Microsoft Fabric Community team will be offering free DP-600 exam vouchers. Prepare now
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
)
)
Solved! Go to Solution.
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! |
Hi @Anonymous
Due to I don't know your data model and values, I build a sample for you.
My sample table:
Group Table:
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:
Select "All" in Group and then select "A" in People:
Select "G1" in Group and Select “A" in People:
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.
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
Hi @Anonymous
Due to I don't know your data model and values, I build a sample for you.
My sample table:
Group Table:
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:
Select "All" in Group and then select "A" in People:
Select "G1" in Group and Select “A" in People:
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.
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! |
Check out the October 2024 Power BI update to learn about new features.
Learn from experts, get hands-on experience, and win awesome prizes.
User | Count |
---|---|
116 | |
108 | |
106 | |
93 | |
69 |
User | Count |
---|---|
167 | |
132 | |
130 | |
96 | |
91 |