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

Join us for an expert-led overview of the tools and concepts you'll need to become a Certified Power BI Data Analyst and pass exam PL-300. Register now.

Reply
pbiwizard
Frequent Visitor

Measure: Summarize by Group and add and IF statement

How to sum/summarize, by group and an IF:

Data As Is   
Product NameTransaction IDJurisdiction TypeGross Amount
P0001123123STATE125.00
P0001123123COUNTY125.00
P0001123123CITY125.00
P0001123123STC125.00
P0001123123STATE125.00
P0001123123CITY125.00
P0001123123STATE25.00
P0002456456STATE10.00

P0002

456456CITY10.00
P0002456456STATE10.01
P0003456456STATE5.00
P0004789789STATE1.50
P0004789789STATE1.50

 

Summary of what it should be   
Product NameTransaction IDProduct NameTotal Gross Amount
P0001123123P0001275.00
P0002456456Multiple/P0002/P000325.01
P0004789789P00043.00

 

Formula 1: 

Gross Sales =
SUMX(
    KEEPFILTERS(
            VALUES(
                'Transactions'[Product_Name]
            )
        ),
    CALCULATE(
        SUMX(
    SUMMARIZE('Transactions', 'Transactions'[Transaction ID], 'Transactions'[Gross Amount] ),
    [Gross Amount])
    )
)
 
This gives me Transaction 123123 for 150.00, but should be Transaction 123123 as 275.00  It returns the sum of non-duplicate values. 
However, I would like for it to return the sum of values, even if it is a duplicate value, IF the Jurisdiction Type is "STATE" is present multiple times. The Jurisdiction Type as State represents a separate, product/purchase. For example, IF I go to the store, and I buy two avocados in one bag, and the cashier rings it up, and then scan more products, and then I have two more avodacos in the same purchase, the receipt will have 2 avocados for 3.00, then Cereal for 5.00, Soup for 2.00, and then 2 MORE avocados for 3.00. However, I want it to combine the avocados into 4 avocados for 6.00. 
 
So I want to continue to group by the Product name and transaction ID, but add and IF the jurisdiction type is "STATE" then also sum/add, even if it is a duplicate value. 
I also used the formula below but returns the same values as Formula 2. 
 
FORMULA 2: 
Gross Sales 1 =
SUMX(
    FILTER(
        'Transactions', [Jurisdiction Type] = "STATE"),
    CALCULATE(
        SUMX(
            SUMMARIZE('Transactions', 'Transactions'[Transaction ID], 'Transactions'[Gross Amount]),
    [Gross Amount])
    )
)
1 ACCEPTED SOLUTION
AlexisOlson
Super User
Super User

I think the issue is including [Gross Amount] in the grouping (rather than aggregating it with a SUM).

If you want to include duplicate rows for STATE but not other jurisdictions, try this:

 

Gross Sales =
VAR _Summary_ =
    SUMMARIZE (
        'Transactions',
        'Transactions'[Product Name],
        'Transactions'[Transaction ID],
        'Transactions'[Jurisdiction Type],
        "@SumAmount", SUM ( 'Transactions'[Gross Amount] ),
        "@MaxAmount", MAX ( 'Transactions'[Gross Amount] )
    )
RETURN
    SUMX (
        _Summary,
        IF (
            'Transactions'[Jurisdiction Type] = "STATE",
            [@SumAmount],
            [@MaxAmount]
        )
    )

 

 

If you always want to count duplicates (not just for STATE), then I think you just do a simple sum:

 

Gross Sales = SUM ( 'Transactions'[Gross Amount] )

 

View solution in original post

1 REPLY 1
AlexisOlson
Super User
Super User

I think the issue is including [Gross Amount] in the grouping (rather than aggregating it with a SUM).

If you want to include duplicate rows for STATE but not other jurisdictions, try this:

 

Gross Sales =
VAR _Summary_ =
    SUMMARIZE (
        'Transactions',
        'Transactions'[Product Name],
        'Transactions'[Transaction ID],
        'Transactions'[Jurisdiction Type],
        "@SumAmount", SUM ( 'Transactions'[Gross Amount] ),
        "@MaxAmount", MAX ( 'Transactions'[Gross Amount] )
    )
RETURN
    SUMX (
        _Summary,
        IF (
            'Transactions'[Jurisdiction Type] = "STATE",
            [@SumAmount],
            [@MaxAmount]
        )
    )

 

 

If you always want to count duplicates (not just for STATE), then I think you just do a simple sum:

 

Gross Sales = SUM ( 'Transactions'[Gross Amount] )

 

Helpful resources

Announcements
Join our Fabric User Panel

Join our Fabric User Panel

This is your chance to engage directly with the engineering team behind Fabric and Power BI. Share your experiences and shape the future.

June 2025 Power BI Update Carousel

Power BI Monthly Update - June 2025

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

June 2025 community update carousel

Fabric Community Update - June 2025

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