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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
smileamile2
Resolver I
Resolver I

Dataset for Paginated report - 1 parameter lookup to 3 columns

I am using a PBI dataset for a PBI Paginated Report, but what I'm trying to do would be a similar use case if building a visual in Power BI desktop too. I have 1 filter, "State". When a state is selected, my dataset needs to filter rows where the selected State is in the Origin field OR Destination field OR Billing field.  How can I set this up so that a State selection (can be multi-select) would check all 3 columns to filter?

7 REPLIES 7
AlexisOlson
Super User
Super User

What does your current DAX query look like?

 

If you show me what it looks like filtered for one column, I think I can extend it to 3.

@AlexisOlson  My dataset has the below relationships. Because there is an active relationship between Origin State and the RegionState dimension, I don't have to do anything too special in the DAX for the parameter.

 

DimensionFactRelationship
RegionState.StateQuery.Origin StateActive
RegionState.StateQuery.Destination StateInactive
RegionState.StateQuery.Billing StateInactive
Calendar.DateQuery.InvDateActive

 

Paginated report dataset query DAX:

 

EVALUATE SUMMARIZECOLUMNS(
'Query'[INVDATE], 
'Query'[DESTINATION STATE],
'Query'[ORIGIN STATE], 
'Query'[BILLING STATE], 
RSCustomDaxFilter(@RegionBranchREGION,EqualToCondition,[Region State].[REGION],String), 
RSCustomDaxFilter(@RegionStateSTATE,EqualToCondition,[Region State].[STATE],String),
FILTER(
	VALUES ('Calendar'[Date]),
	  ('Calendar'[Date] >= DATEVALUE( @FromCalendarDate ))
	  && ('Calendar'[Date] <= DATEVALUE( @ToCalendarDate ))
),
 "NET_REVENUE", [NET_REVENUE])

 

Would something like this work?

EVALUATE
SUMMARIZECOLUMNS (
    'Query'[INVDATE],
    'Query'[DESTINATION STATE],
    'Query'[ORIGIN STATE],
    'Query'[BILLING STATE],
    TREATAS ( { @RegionBranchREGION }, 'Region State'[REGION] ),
    TREATAS ( { @RegionStateSTATE }, 'Region State'[STATE] ),
    FILTER (
        VALUES ( 'Calendar'[Date] ),
        ( 'Calendar'[Date] >= DATEVALUE ( @FromCalendarDate ) )
            && ( 'Calendar'[Date] <= DATEVALUE ( @ToCalendarDate ) )
    ),
    "NET_REVENUE_DESTINATION",
        CALCULATE (
            [NET_REVENUE],
            USERELATIONSHIP ( 'Region State'[STATE], 'Query'[DESTINATION STATE] )
        ),
    "NET_REVENUE_ORIGIN",
        CALCULATE (
            [NET_REVENUE],
            USERELATIONSHIP ( 'Region State'[STATE], 'Query'[ORIGIN STATE] )
        ),
    "NET_REVENUE_BILLING",
        CALCULATE (
            [NET_REVENUE],
            USERELATIONSHIP ( 'Region State'[STATE], 'Query'[BILLING STATE] )
        )
)

@AlexisOlson  So, I actually took out a bunch of other columns from the query to keep it simple. I actually have about 30 measures overall that need to be in the dataset, not just Net Revenue, so this would be very difficult to manage. 

Also I'm pretty sure I have to keep the RSCustomDaxFilter for the State filter (I removed Region, not needed). 

You can filter 'Query' as you specify like this (you don't necessarily need RSCustomDaxFilter, at least not for a single value parameter):

FILTER (
    'Query',
    'Query'[DESTINATION STATE] = @RegionStateSTATE
        || 'Query'[ORIGIN STATE] = @RegionStateSTATE
        || 'Query'[BILLING STATE] = @RegionStateSTATE
)

 

However, all your measures will be calculated under the active relationship. This satifies what your original post asked for but I suspect it might not help that much more broadly.

@AlexisOlson  Hm, it seems to work when one is selected, but State is in fact a multi-select parameter

I've not done this myself but it appears to be doable.

 

Please take a look at these sources:

https://blog.crossjoin.co.uk/2012/06/01/handling-ssrs-multi-valued-parameters-in-dax-queries/

https://datakuity.com/2019/01/07/ssrs-multi-value-parameter-in-dax-2/

https://community.powerbi.com/t5/Desktop/Report-Builder-Converting-DAX-Query-to-Multi-Select-Paramet...

 

Something like this maybe?

 

DEFINE
    VAR PathSTATE =
        SUBSTITUTE (
            SUBSTITUTE ( SUBSTITUTE ( @RegionStateSTATE, "{ ", "" ), " }", "" ),
            ",",
            "|"
        )
    VAR FilterSTATE =
        CALCULATETABLE (
            'Query',
            PATHCONTAINS ( PathSTATE, 'Query'[DESTINATION STATE] )
                || PATHCONTAINS ( PathSTATE, 'Query'[ORIGIN STATE] )
                || PATHCONTAINS ( PathSTATE, 'Query'[BILLING STATE] )
        )
    VAR FilterDate =
        FILTER (
            VALUES ( 'Calendar'[Date] ),
            ( 'Calendar'[Date] >= DATEVALUE ( @FromCalendarDate ) )
                && ( 'Calendar'[Date] <= DATEVALUE ( @ToCalendarDate ) )
        )

EVALUATE
SUMMARIZECOLUMNS (
    'Query'[INVDATE],
    'Query'[DESTINATION STATE],
    'Query'[ORIGIN STATE],
    'Query'[BILLING STATE],
    FilterSTATE,
    FilterDate,
    "NET_REVENUE", [NET_REVENUE]
)

This probably isn't very efficient but the first step is to get it working at all.

 

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

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

April Fabric Community Update

Fabric Community Update - April 2024

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