Power BI is turning 10! Tune in for a special live episode on July 24 with behind-the-scenes stories, product evolution highlights, and a sneak peek at what’s in store for the future.
Save the dateEnhance your career with this limited time 50% discount on Fabric and Power BI exams. Ends August 31st. Request your voucher.
Hello everyone,
I have a table with numerous, but simple measures and different categorization columns. The two measures I need to use are for number of certificates and number of denials. Both are using similar count functions, CALCULATE(COUNT('Table'[ID]),FILTER('Table','Table'[Qualifier]="Cert")) and CALCULATE(COUNT('Table'[ID]),FILTER('Table','Table'[Qualifier]="Denial")). My problem is that I need to find the Cert Rate, Certs/(Certs + Denials), in a matrix that has the Year/Quarter and U.S. State as rows and Cert Category in the column, however the Cert Rate must be calculated using the total Certs + Denials across each row (so the total for each state, year, and quarter).
The problem I have is two-fold. The first is that I need it to calculate the Cert Rate across the entire column, as in the total of (Certs + Denials) must ignore the Cert Category, and second is that the Denials records do not have a Cert Category associated with them (the value for Cert Category is blank whereas for Certs records, there is always a value). They are all in one large table.
I have tried looking at different topics, but couldn't find one that has the same issue.
Solved! Go to Solution.
Hi, @ngoodweiler
Based on your description, and the data you provided, I tried to create two matrices like yours using the following sample data:
I created a measure using the following DAX expression:
MEASURE =
VAR _table =
SUMMARIZE (
ALLSELECTED ( 'Table' ),
'Table'[State],
'Table'[Date],
"Year", YEAR ( 'Table'[Date] ),
"Denis Total",
CALCULATE (
SUM ( 'Table'[value] ),
FILTER ( 'Table', 'Table'[Qualifier] = "Denial" )
)
)
VAR _table1 =
SUMMARIZE (
_table,
'Table'[State],
[Year],
"Denis",
VAR _current_year = [Year]
VAR _state = 'Table'[State]
RETURN
SUMX (
FILTER ( _table, 'Table'[State] = _state && [Year] = _current_year ),
[Denis Total]
)
)
VAR _table2 =
FILTER (
SUMMARIZE (
ALLSELECTED ( 'Table' ),
'Table'[State],
'Table'[Category],
'Table'[Date],
"Year", YEAR ( 'Table'[Date] ),
"value", CALCULATE ( SUM ( 'Table'[value] ) )
),
'Table'[Category] <> BLANK ()
)
VAR _table3 =
SUMMARIZE (
_table2,
'Table'[State],
'Table'[Category],
[Year],
"value1",
VAR _current_year = [Year]
VAR _state = 'Table'[State]
VAR _category = 'Table'[Category]
RETURN
SUMX (
FILTER (
_table2,
'Table'[Category] = _category
&& 'Table'[State] = _state
&& [Year] = _current_year
),
[value]
)
)
VAR _current_state =
SELECTEDVALUE ( 'Table'[State] )
VAR _current_year =
SELECTEDVALUE ( 'Table'[Date].[Year] )
VAR _current_category =
SELECTEDVALUE ( 'Table'[Category] )
VAR _table4 =
FILTER ( _table1, 'Table'[State] = _current_state && [Year] = _current_year )
VAR _table5 =
FILTER (
_table3,
'Table'[State] = _current_state
&& 'Table'[Category] = _current_category
&& [Year] = _current_year
)
VAR _dens =
CALCULATE ( MAXX ( _table4, [Denis] ) )
RETURN
DIVIDE (
MAXX ( _table5, [value1] ),
_dens
+ SUMX (
FILTER ( _table3, 'Table'[State] = _current_state && [Year] = _current_year ),
[value1]
)
)
Put this measure in the matrix and the result is as follows:
I've provided the PBIX file used this time below.
How to Get Your Question Answered Quickly
If it does not help, please provide more details with your desired output and pbix file without privacy information (or some sample data) .
Best Regards
Jianpeng Li
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Hi, @ngoodweiler
Based on your description, and the data you provided, I tried to create two matrices like yours using the following sample data:
I created a measure using the following DAX expression:
MEASURE =
VAR _table =
SUMMARIZE (
ALLSELECTED ( 'Table' ),
'Table'[State],
'Table'[Date],
"Year", YEAR ( 'Table'[Date] ),
"Denis Total",
CALCULATE (
SUM ( 'Table'[value] ),
FILTER ( 'Table', 'Table'[Qualifier] = "Denial" )
)
)
VAR _table1 =
SUMMARIZE (
_table,
'Table'[State],
[Year],
"Denis",
VAR _current_year = [Year]
VAR _state = 'Table'[State]
RETURN
SUMX (
FILTER ( _table, 'Table'[State] = _state && [Year] = _current_year ),
[Denis Total]
)
)
VAR _table2 =
FILTER (
SUMMARIZE (
ALLSELECTED ( 'Table' ),
'Table'[State],
'Table'[Category],
'Table'[Date],
"Year", YEAR ( 'Table'[Date] ),
"value", CALCULATE ( SUM ( 'Table'[value] ) )
),
'Table'[Category] <> BLANK ()
)
VAR _table3 =
SUMMARIZE (
_table2,
'Table'[State],
'Table'[Category],
[Year],
"value1",
VAR _current_year = [Year]
VAR _state = 'Table'[State]
VAR _category = 'Table'[Category]
RETURN
SUMX (
FILTER (
_table2,
'Table'[Category] = _category
&& 'Table'[State] = _state
&& [Year] = _current_year
),
[value]
)
)
VAR _current_state =
SELECTEDVALUE ( 'Table'[State] )
VAR _current_year =
SELECTEDVALUE ( 'Table'[Date].[Year] )
VAR _current_category =
SELECTEDVALUE ( 'Table'[Category] )
VAR _table4 =
FILTER ( _table1, 'Table'[State] = _current_state && [Year] = _current_year )
VAR _table5 =
FILTER (
_table3,
'Table'[State] = _current_state
&& 'Table'[Category] = _current_category
&& [Year] = _current_year
)
VAR _dens =
CALCULATE ( MAXX ( _table4, [Denis] ) )
RETURN
DIVIDE (
MAXX ( _table5, [value1] ),
_dens
+ SUMX (
FILTER ( _table3, 'Table'[State] = _current_state && [Year] = _current_year ),
[value1]
)
)
Put this measure in the matrix and the result is as follows:
I've provided the PBIX file used this time below.
How to Get Your Question Answered Quickly
If it does not help, please provide more details with your desired output and pbix file without privacy information (or some sample data) .
Best Regards
Jianpeng Li
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
This was great, thank you for the help!
User | Count |
---|---|
25 | |
12 | |
8 | |
6 | |
6 |
User | Count |
---|---|
26 | |
12 | |
11 | |
8 | |
6 |