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

Get inspired! Check out the entries from the Power BI DataViz World Championships preliminary rounds and give kudos to your favorites. View the vizzies.

Reply
CScottP
Regular Visitor

Max Value based upon two columns with distant filter

TYPEACTIONMODIFICATIONDATEITEMSSPLIT_MODORDER_ACTIONMOD_ORDER EXPECTED RESULTSITEMS
WIDGET-A BASE01-Dec-2457000 WIDGET-A56
WIDGET-AADDBASE01-Dec-2457011 WIDGET-B75
WIDGET-ACHANGE FROMBASE01-Dec-2457000 WIDGET-C0
WIDGET-ANO CHANGEBASE01-Dec-2457044   
WIDGET-ACHANGE FROMCHANGE 0301-Dec-2457303 TOTAL131
WIDGET-ACHANGE TOCHANGE 0301-Dec-2457336   
WIDGET-ACHANGE TOCHANGE 0401-Dec-2456437   
WIDGET-ANO CHANGECHANGE 0401-Dec-2456448   
WIDGET-BCHANGE FROMBASE22-Dec-2455000   
WIDGET-B BASE22-Dec-2423000   
WIDGET-BADDBASE22-Dec-2455011   
WIDGET-BNO CHANGEBASE22-Dec-2455044   
WIDGET-BCHANGE FROMCHANGE 0322-Dec-2455303   
WIDGET-BNO CHANGECHANGE 0322-Dec-2455347   
WIDGET-BCHANGE FROMCHANGE 0422-Dec-2455404   
WIDGET-BCHANGE TOCHANGE 0422-Dec-24100437   
WIDGET-BCHANGE TOCHANGE 0522-Dec-2475538   
WIDGET-BNO CHANGECHANGE 0522-Dec-2475549   
WIDGET-CCHANGE FROMBASE22-Dec-2420000   
WIDGET-CADDBASE22-Dec-2420011   
WIDGET-CCHANGE TOBASE22-Dec-2420033   
WIDGET-CDELETE 22-Dec-2420055   

Trying to filter/group by "TYPE"

Then get "ITEMS" value based upon MAX "MOD_ORDER"

If "ACTION" is "DELETE" then reflect "ITEMS" value as "0" (Zero)  

1 ACCEPTED SOLUTION
quantumudit
Super User
Super User

Hello @CScottP 
Thank you for providing the dataset and the expected result table.

You can create the following DAX measure to calculate number of items:

Item Count = 
VAR _maxModOrd = MAX ( 'Table'[MOD_ORDER] )
VAR _actionValues = CALCULATE ( MAX ( 'Table'[ACTION] ), 'Table'[MOD_ORDER] = _maxModOrd )
VAR _items = CALCULATE ( SUM ( 'Table'[ITEMS] ), 'Table'[MOD_ORDER] = _maxModOrd )
VAR _trueItems = IF ( _actionValues = "DELETE", 0, _items ) 

// For Total Calculation
VAR _summarizedTable =
    SUMMARIZE (
        'Table',
        'Table'[TYPE],
        "max_mod_order", CALCULATE ( MAX ( 'Table'[MOD_ORDER] ) )
    )

VAR _extendedTotalTable =
    FILTER (
        ADDCOLUMNS (
            _summarizedTable,
            "action",
                LOOKUPVALUE (
                    'Table'[ACTION],
                    'Table'[TYPE], [TYPE],
                    'Table'[MOD_ORDER], [max_mod_order]
                ),
            "items",
                LOOKUPVALUE (
                    'Table'[ITEMS],
                    'Table'[TYPE], [TYPE],
                    'Table'[MOD_ORDER], [max_mod_order]
                )
        ),
        [action] <> "DELETE"
    )
VAR _totalItems =
    SUMX ( _extendedTotalTable, [items] )
RETURN
    IF ( ISINSCOPE ( 'Table'[TYPE] ), _trueItems, _totalItems )

Here is the screenshot of the result I got after applyint this DAX measure:

 

quantumudit_0-1739304519224.png

 

Here is the screenshot of the DAX measure:

 

quantumudit_1-1739304579205.png

 

I am also attaching the working Power BI file that I have used to solve your query, in case you need it.

 

Best Regards,
Udit

If this post helps, then please consider Accepting it as the solution to help the other members find it more quickly.
Appreciate your Kudo 👍

🚀 Let's Connect: LinkedIn || YouTube || Medium || GitHub
Visit My Linktree: LinkTree

 

Pround to be a Super User

 

View solution in original post

4 REPLIES 4
quantumudit
Super User
Super User

Hello @CScottP 
Thank you for providing the dataset and the expected result table.

You can create the following DAX measure to calculate number of items:

Item Count = 
VAR _maxModOrd = MAX ( 'Table'[MOD_ORDER] )
VAR _actionValues = CALCULATE ( MAX ( 'Table'[ACTION] ), 'Table'[MOD_ORDER] = _maxModOrd )
VAR _items = CALCULATE ( SUM ( 'Table'[ITEMS] ), 'Table'[MOD_ORDER] = _maxModOrd )
VAR _trueItems = IF ( _actionValues = "DELETE", 0, _items ) 

// For Total Calculation
VAR _summarizedTable =
    SUMMARIZE (
        'Table',
        'Table'[TYPE],
        "max_mod_order", CALCULATE ( MAX ( 'Table'[MOD_ORDER] ) )
    )

VAR _extendedTotalTable =
    FILTER (
        ADDCOLUMNS (
            _summarizedTable,
            "action",
                LOOKUPVALUE (
                    'Table'[ACTION],
                    'Table'[TYPE], [TYPE],
                    'Table'[MOD_ORDER], [max_mod_order]
                ),
            "items",
                LOOKUPVALUE (
                    'Table'[ITEMS],
                    'Table'[TYPE], [TYPE],
                    'Table'[MOD_ORDER], [max_mod_order]
                )
        ),
        [action] <> "DELETE"
    )
VAR _totalItems =
    SUMX ( _extendedTotalTable, [items] )
RETURN
    IF ( ISINSCOPE ( 'Table'[TYPE] ), _trueItems, _totalItems )

Here is the screenshot of the result I got after applyint this DAX measure:

 

quantumudit_0-1739304519224.png

 

Here is the screenshot of the DAX measure:

 

quantumudit_1-1739304579205.png

 

I am also attaching the working Power BI file that I have used to solve your query, in case you need it.

 

Best Regards,
Udit

If this post helps, then please consider Accepting it as the solution to help the other members find it more quickly.
Appreciate your Kudo 👍

🚀 Let's Connect: LinkedIn || YouTube || Medium || GitHub
Visit My Linktree: LinkTree

 

Pround to be a Super User

 

When I apply to larger data volume I'm getting the following, I did pair it off to same column names and checked column types as well.

 

Mdx Script (Model) (47,37) Clulation error in measue with card & Multi card in your example.

Measure showed - The function SUM can not work with values of type string.

 

Thanks in advance!

Hello @CScottP 

I suspect the issue lies within the data model. Sharing a sample, anonymized Power BI file would be extremely helpful for me to diagnose the problem.

 

DAX formulas generally perform consistently regardless of data size, provided the data types and other relevant factors are identical. Since it's not working as expected, I'll need to examine the Power BI file and other details to understand why.

 

If you prefer not to share the anonymized Power BI file publicly, please feel free to send it to me directly through message.

 

Thanks,

Udit

Sir, 

 

Perfect!  Thank you for your time and effort, greatly apprecated!

 

Scott

Helpful resources

Announcements
Las Vegas 2025

Join us at the Microsoft Fabric Community Conference

March 31 - April 2, 2025, in Las Vegas, Nevada. Use code FABINSIDER for a $400 discount!

FebPBI_Carousel

Power BI Monthly Update - February 2025

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

March2025 Carousel

Fabric Community Update - March 2025

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

Top Solution Authors
Top Kudoed Authors