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
JJRubio
Regular Visitor

Conditional calculation based on three slicers

I have a project where I need to sum up values from one of four column which is determined three slicers (Geo Hierarchy, Gross/Net, and Shrunk/Unshrunk).

I was able to get this to work, using an example I found online, for one of two columns and two slicers (see below) but I can't figure out how to make it work with as described above.

 

 

Variable GrossNet BOE = 
SWITCH(
    TRUE(),
    -------------- Entity --------------
    SELECTEDVALUE(P_HIERARCHY_LVL[Field]) = "Entity", 
    CALCULATE(
        IF(
            HASONEVALUE(P_GROSS_NET[Gross Net]),
            SWITCH(
                VALUES(P_GROSS_NET[Gross Net]),
                    "Gross", SUM(PRODUCTION_AREA_PERF[gross_sales_boe]),
                    "Net", SUM(PRODUCTION_AREA_PERF[net_sales_boe])
            ),
        SUM(PRODUCTION_AREA_PERF[gross_sales_boe])
        ),
        USERELATIONSHIP(P_HIERARCHY_LVL[Category], PROD_AREA_COUNTRY[country_cd])
    ),

    -------------------- Asset --------------
   SELECTEDVALUE(P_HIERARCHY_LVL[Field]) = "Asset", 
   CALCULATE(
        IF(
            HASONEVALUE(P_GROSS_NET[Gross Net]),
            SWITCH(
                VALUES(P_GROSS_NET[Gross Net]),
                    "Gross", SUM(PRODUCTION_AREA_PERF[gross_sales_boe]),
                    "Net", SUM(PRODUCTION_AREA_PERF[net_sales_boe])
            ),
        SUM(PRODUCTION_AREA_PERF[gross_sales_boe])
        ),
        USERELATIONSHIP(P_HIERARCHY_LVL[Category], PROD_AREA_ASSET[asset_name])
    ),

    -------------------- PA ----------------
    SELECTEDVALUE(P_HIERARCHY_LVL[Field]) = "Production Area/Platform", 
    CALCULATE(
        IF(
            HASONEVALUE(P_GROSS_NET[Gross Net]),
            SWITCH(
                VALUES(P_GROSS_NET[Gross Net]),
                    "Gross", SUM(PRODUCTION_AREA_PERF[gross_sales_boe]),
                    "Net", SUM(PRODUCTION_AREA_PERF[net_sales_boe])
            ),
        SUM(PRODUCTION_AREA_PERF[gross_sales_boe])
        ),
        USERELATIONSHIP(P_HIERARCHY_LVL[Category], PROD_AREA_PLATFORM[production_area_abbr])
    ),
    BLANK()
)

 

 

I'm pretty new at Dax.  I think what I have is close, I just need help figuring out how to do something like this within the IF statement of the above code:

 

 

SUM(
    IF(GrossNet = 'Gross' AND ShrunkUnshrunk = 'Shrunk', 'GrossShrunkBOE',
       IF(GrossNet = 'Gross' AND ShrunkUnshrunk = 'Unshrunk', 'GrossUnshrunkBOE',
          IF(GrossNet = 'Net' AND ShrunkUnshrunk = 'Shrunk', 'NetShrunkBOE',
             IF(GrossNet = 'Net' AND ShrunkUnshrunk = 'Unshrunk', 'NetUnshrunkBOE',0
                )
             )
          )
      )
   )

 

 

Any help I can get is greatly appreicated.

1 ACCEPTED SOLUTION
v-rzhou-msft
Community Support
Community Support

Hi @JJRubio ,

 

SUM(
    IF(GrossNet = 'Gross' AND ShrunkUnshrunk = 'Shrunk', 'GrossShrunkBOE',
       IF(GrossNet = 'Gross' AND ShrunkUnshrunk = 'Unshrunk', 'GrossUnshrunkBOE',
          IF(GrossNet = 'Net' AND ShrunkUnshrunk = 'Shrunk', 'NetShrunkBOE',
             IF(GrossNet = 'Net' AND ShrunkUnshrunk = 'Unshrunk', 'NetUnshrunkBOE',0
                )
             )
          )
      )
   )

Are 'GrossShrunkBOE'/'GrossUnshrunkBOE'/'NetShrunkBOE'/'NetUnshrunkBOE' in true result part of IF function measures which will return number type value? I see your measure will return 0 in last false result.

According to your code, I think there should be two slicers GrossNet and ShrunkUnshrunk in your data model.

Measure = 
VAR _SELECT_GrossNet = SELECTEDVALUE('Slicer1'[GrossNet])
VAR _SELECT_ShrunkUnshrunk = SELECTEDVALUE('Slicer2'[ShrunkUnshrunk])
RETURN
SWITCH(
TRUE(),
_SELECT_GrossNet = 'Gross' && _SELECT_ShrunkUnshrunk = 'Shrunk', [GrossShrunkBOE],
_SELECT_GrossNet = 'Gross' && _SELECT_ShrunkUnshrunk = 'Unshrunk', [GrossUnshrunkBOE],
_SELECT_GrossNet = 'Net' && _SELECT_ShrunkUnshrunk = 'Shrunk', [NetShrunkBOE],
_SELECT_GrossNet = 'Net' && _SELECT_ShrunkUnshrunk = 'Unshrunk', [NetUnshrunkBOE],
0
)

Do not sum the measure in one code unless you create a virtual table in your measure. Try sumx function to sum your measure.

SUM = SUMX('DataTable',[Measure])

 

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

1 REPLY 1
v-rzhou-msft
Community Support
Community Support

Hi @JJRubio ,

 

SUM(
    IF(GrossNet = 'Gross' AND ShrunkUnshrunk = 'Shrunk', 'GrossShrunkBOE',
       IF(GrossNet = 'Gross' AND ShrunkUnshrunk = 'Unshrunk', 'GrossUnshrunkBOE',
          IF(GrossNet = 'Net' AND ShrunkUnshrunk = 'Shrunk', 'NetShrunkBOE',
             IF(GrossNet = 'Net' AND ShrunkUnshrunk = 'Unshrunk', 'NetUnshrunkBOE',0
                )
             )
          )
      )
   )

Are 'GrossShrunkBOE'/'GrossUnshrunkBOE'/'NetShrunkBOE'/'NetUnshrunkBOE' in true result part of IF function measures which will return number type value? I see your measure will return 0 in last false result.

According to your code, I think there should be two slicers GrossNet and ShrunkUnshrunk in your data model.

Measure = 
VAR _SELECT_GrossNet = SELECTEDVALUE('Slicer1'[GrossNet])
VAR _SELECT_ShrunkUnshrunk = SELECTEDVALUE('Slicer2'[ShrunkUnshrunk])
RETURN
SWITCH(
TRUE(),
_SELECT_GrossNet = 'Gross' && _SELECT_ShrunkUnshrunk = 'Shrunk', [GrossShrunkBOE],
_SELECT_GrossNet = 'Gross' && _SELECT_ShrunkUnshrunk = 'Unshrunk', [GrossUnshrunkBOE],
_SELECT_GrossNet = 'Net' && _SELECT_ShrunkUnshrunk = 'Shrunk', [NetShrunkBOE],
_SELECT_GrossNet = 'Net' && _SELECT_ShrunkUnshrunk = 'Unshrunk', [NetUnshrunkBOE],
0
)

Do not sum the measure in one code unless you create a virtual table in your measure. Try sumx function to sum your measure.

SUM = SUMX('DataTable',[Measure])

 

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.

 

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.