Power BI is turning 10, and we’re marking the occasion with a special community challenge. Use your creativity to tell a story, uncover trends, or highlight something unexpected.
Get startedJoin 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.
How to sum/summarize, by group and an IF:
Data As Is | |||
Product Name | Transaction ID | Jurisdiction Type | Gross Amount |
P0001 | 123123 | STATE | 125.00 |
P0001 | 123123 | COUNTY | 125.00 |
P0001 | 123123 | CITY | 125.00 |
P0001 | 123123 | STC | 125.00 |
P0001 | 123123 | STATE | 125.00 |
P0001 | 123123 | CITY | 125.00 |
P0001 | 123123 | STATE | 25.00 |
P0002 | 456456 | STATE | 10.00 |
P0002 | 456456 | CITY | 10.00 |
P0002 | 456456 | STATE | 10.01 |
P0003 | 456456 | STATE | 5.00 |
P0004 | 789789 | STATE | 1.50 |
P0004 | 789789 | STATE | 1.50 |
Summary of what it should be | |||
Product Name | Transaction ID | Product Name | Total Gross Amount |
P0001 | 123123 | P0001 | 275.00 |
P0002 | 456456 | Multiple/P0002/P0003 | 25.01 |
P0004 | 789789 | P0004 | 3.00 |
Formula 1:
Solved! Go to Solution.
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] )
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] )
This is your chance to engage directly with the engineering team behind Fabric and Power BI. Share your experiences and shape the future.
Check out the June 2025 Power BI update to learn about new features.
User | Count |
---|---|
14 | |
10 | |
10 | |
10 | |
9 |
User | Count |
---|---|
20 | |
13 | |
12 | |
11 | |
8 |