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.
Dear all,
I am working with a large and given data model in our company. My target is to create a flexible key figures sheet. Here is a short extract of some columns in the model.
Type of Data | KPI | Value |
Forecast1 | Revenues | 100 |
Forecast2 | Revenues | 110 |
Actuals | Revenues | 50 |
Actuals PY | Revenues | 45 |
Forecast1 | Orders | 120 |
Forecast2 | Orders | 105 |
Actuals | Orders | 95 |
Actuals PY | Orders | 50 |
Forecast1 | Profit | 30 |
Forecast2 | Profit | 35 |
Actuals | Profit | 25 |
Actuals PY | Profit | 15 |
I would like to create a measure for each KPI and for each Type of data so that I can flexible calculate with it every month.
The result should look pretty much like this:
Actuals PY | Actuals | Forecast1 | Forecast2 | delta to FC PM | |
Orders | |||||
Revenues | |||||
Profit | |||||
Profit margin% |
I was able to generate the KPI's by using an if formula. What would be an efficient way to calculate the type of data measures?
Many thanks for your support!
Solved! Go to Solution.
Hi
KPI Value = VAR CurrentKPI = SELECTEDVALUE('YourTable'[KPI]) VAR CurrentType = SELECTEDVALUE('YourTable'[Type of Data]) RETURN SWITCH( TRUE(), CurrentKPI = "Profit margin%", DIVIDE( CALCULATE( SUM('YourTable'[Value]), 'YourTable'[KPI] = "Profit", 'YourTable'[Type of Data] = CurrentType ), CALCULATE( SUM('YourTable'[Value]), 'YourTable'[KPI] = "Revenues", 'YourTable'[Type of Data] = CurrentType ) ), SUM('YourTable'[Value]) )
Delta to FC PM = VAR Actuals = CALCULATE( SUM('YourTable'[Value]), 'YourTable'[Type of Data] = "Actuals" ) VAR Forecast1 = CALCULATE( SUM('YourTable'[Value]), 'YourTable'[Type of Data] = "Forecast1" ) RETURN Actuals - Forecast1
Benefits of This Approach
KPI |
Actuals PY |
Actuals |
Forecast1 |
Forecast2 |
Delta to FC PM |
Orders |
50 |
95 |
120 |
105 |
(Actuals - FC1) |
Revenues |
45 |
50 |
100 |
110 |
(Actuals - FC1) |
Profit |
15 |
25 |
30 |
35 |
(Actuals - FC1) |
Profit margin % |
33.3% |
50% |
30% |
31.8% |
N/A |
Notes
If this post helps, please consider accepting it as the solution to help the other members find it more quickly.
Appreciate your Kudos!!
Hi @M_Chris
You need to update the current switch and add Format function to change the format of data for the items you wanna see them in % format.
Like this:
KPI Value =
VAR CurrentKPI =
SELECTEDVALUE ( 'YourTable'[KPI] )
VAR CurrentType =
SELECTEDVALUE ( 'YourTable'[Type of Data] )
RETURN
SWITCH (
TRUE (),
CurrentKPI = "Profit margin%",
FORMAT (
DIVIDE (
CALCULATE (
SUM ( 'YourTable'[Value] ),
'YourTable'[KPI] = "Profit",
'YourTable'[Type of Data] = CurrentType
),
CALCULATE (
SUM ( 'YourTable'[Value] ),
'YourTable'[KPI] = "Revenues",
'YourTable'[Type of Data] = CurrentType
)
),
"Percent"
),
SUM ( 'YourTable'[Value] )
)
If this post helps, please consider accepting it as the solution to help the other members find it more quickly.
Appreciate your Kudos!!
LinkedIn|Twitter|Blog |YouTube
Hi @M_Chris
Try this:
KPI Value =
VAR CurrentKPI =
SELECTEDVALUE ( 'YourTable'[KPI] )
VAR CurrentType =
SELECTEDVALUE ( 'YourTable'[Type of Data] )
RETURN
SWITCH (
TRUE (),
CurrentKPI = "Profit margin%",
FORMAT (
DIVIDE (
CALCULATE (
SUM ( 'YourTable'[Value] ),
'YourTable'[KPI] = "Profit",
'YourTable'[Type of Data] = CurrentType
),
CALCULATE (
SUM ( 'YourTable'[Value] ),
'YourTable'[KPI] = "Revenues",
'YourTable'[Type of Data] = CurrentType
)
),
"0.0%"
),
SUM ( 'YourTable'[Value] )
)
Hope this solve your problem and please accept all 3 version of my post as solutions to help others.
Appreciate your Kudos!!
@VahidDM thank you very much. That is exactly what I have been looking for.
It is working out quiet nice. The only thing I am not yet able to get done is the change of the layout so that the margin appears in percentages. I am only able to change the whole set of data to decimal places but not one single row into percentages.
Cheers and really appreciated.
Hi @M_Chris
You need to update the current switch and add Format function to change the format of data for the items you wanna see them in % format.
Like this:
KPI Value =
VAR CurrentKPI =
SELECTEDVALUE ( 'YourTable'[KPI] )
VAR CurrentType =
SELECTEDVALUE ( 'YourTable'[Type of Data] )
RETURN
SWITCH (
TRUE (),
CurrentKPI = "Profit margin%",
FORMAT (
DIVIDE (
CALCULATE (
SUM ( 'YourTable'[Value] ),
'YourTable'[KPI] = "Profit",
'YourTable'[Type of Data] = CurrentType
),
CALCULATE (
SUM ( 'YourTable'[Value] ),
'YourTable'[KPI] = "Revenues",
'YourTable'[Type of Data] = CurrentType
)
),
"Percent"
),
SUM ( 'YourTable'[Value] )
)
If this post helps, please consider accepting it as the solution to help the other members find it more quickly.
Appreciate your Kudos!!
LinkedIn|Twitter|Blog |YouTube
@VahidDM great job! I am really impressed. it works awesome. Just one minor thing: currently it shows the percentages with two decimal places. is it possible to include in the format fomular that the percentage should appear with only one decimal place? Of course I will accept this as solution. really appreciated....
Hi @M_Chris
Try this:
KPI Value =
VAR CurrentKPI =
SELECTEDVALUE ( 'YourTable'[KPI] )
VAR CurrentType =
SELECTEDVALUE ( 'YourTable'[Type of Data] )
RETURN
SWITCH (
TRUE (),
CurrentKPI = "Profit margin%",
FORMAT (
DIVIDE (
CALCULATE (
SUM ( 'YourTable'[Value] ),
'YourTable'[KPI] = "Profit",
'YourTable'[Type of Data] = CurrentType
),
CALCULATE (
SUM ( 'YourTable'[Value] ),
'YourTable'[KPI] = "Revenues",
'YourTable'[Type of Data] = CurrentType
)
),
"0.0%"
),
SUM ( 'YourTable'[Value] )
)
Hope this solve your problem and please accept all 3 version of my post as solutions to help others.
Appreciate your Kudos!!
Hi all,
@VahidDM the solution forks very well so far. I was able to create a first key figures sheet. Currently I added a separate column for sorting/ranking reasons of my KPI's which I can change manually in the background. When adding another "Ranking" column my calculcated margins disappear.
BEFORE:
AFTER (without margins)
I do not understand why the calculcated margins are disappearing because I thought I linked them between KPI and Data Type.
Do you have any idea with the margins are disappearing when I add the additional ranking column as first column? Any idea how to adjust the DAX?
Many thanks
Chris
Hi
KPI Value = VAR CurrentKPI = SELECTEDVALUE('YourTable'[KPI]) VAR CurrentType = SELECTEDVALUE('YourTable'[Type of Data]) RETURN SWITCH( TRUE(), CurrentKPI = "Profit margin%", DIVIDE( CALCULATE( SUM('YourTable'[Value]), 'YourTable'[KPI] = "Profit", 'YourTable'[Type of Data] = CurrentType ), CALCULATE( SUM('YourTable'[Value]), 'YourTable'[KPI] = "Revenues", 'YourTable'[Type of Data] = CurrentType ) ), SUM('YourTable'[Value]) )
Delta to FC PM = VAR Actuals = CALCULATE( SUM('YourTable'[Value]), 'YourTable'[Type of Data] = "Actuals" ) VAR Forecast1 = CALCULATE( SUM('YourTable'[Value]), 'YourTable'[Type of Data] = "Forecast1" ) RETURN Actuals - Forecast1
Benefits of This Approach
KPI |
Actuals PY |
Actuals |
Forecast1 |
Forecast2 |
Delta to FC PM |
Orders |
50 |
95 |
120 |
105 |
(Actuals - FC1) |
Revenues |
45 |
50 |
100 |
110 |
(Actuals - FC1) |
Profit |
15 |
25 |
30 |
35 |
(Actuals - FC1) |
Profit margin % |
33.3% |
50% |
30% |
31.8% |
N/A |
Notes
If this post helps, please consider accepting it as the solution to help the other members find it more quickly.
Appreciate your Kudos!!
I thought it makes sense to have e.g. a calculated measure for the individual KPI"s. like Revenues or Profit so that I can calculate the Profit margin in % afterwards. Therefore I am looking for the DAX formula to create e.g. a separate Measure to show the Profit in the rows across all type of data. I tried with the calculate fucntion so far.
hi @M_Chris ,
as i see, type of data can work well with your KPI measures, what do you mean by "efficient way to calculate the type of data measures"? could you elaborate that?
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 |
---|---|
11 | |
10 | |
10 | |
9 | |
8 |
User | Count |
---|---|
17 | |
13 | |
12 | |
11 | |
8 |