Microsoft Fabric Community Conference 2025, March 31 - April 2, Las Vegas, Nevada. Use code MSCUST for a $150 discount.
Register nowThe Power BI DataViz World Championships are on! With four chances to enter, you could win a spot in the LIVE Grand Finale in Las Vegas. Show off your skills.
Dear all,
Based on Nate Chamberlain’s “DataKey” I prepared the below visual for which I used the following data:
“DateKey”[Month]
“DateKey”[Month]
“Data”[AmountEUR]
Is it possible to leave the column “Gesamt”?
Now I do need further measures and don’t know how to handle.
I think for the specialists our there this is very easy, but I do not get it. Even when trying to adapt posted solutions, I do not get it worked…
Solved! Go to Solution.
Hi, @Orstenpowers
To create a measure like this:
_total =
var _21=
CALCULATE (
SUM ( [value] ),
FILTER ( ALLEXCEPT ( 'Table', 'Table'[MMM] ), [Year] = 2021 )
)
var _20=
CALCULATE (
SUM ( [value] ),
FILTER ( ALLEXCEPT ( 'Table', 'Table'[MMM] ), [Year] = 2020 )
)
return
IF (
ISINSCOPE ( 'Table'[Year] ),
SUM ( [value] ),
IF(ISBLANK(_21),_20,_21-_20)
)
Cumulative figures:
Cumulative figures =
var _c21=
CALCULATE(SUM('Table'[value]),FILTER(ALL('Table'),'Table'[Year]=2021&&'Table'[Date]<=MAX('Table'[Date])))
var _c20=
CALCULATE(SUM('Table'[value]),FILTER(ALL('Table'),'Table'[Year]=2020&&MONTH('Table'[Date])<=MONTH(MAX('Table'[Date]))))
var _cumulative=
CALCULATE(SUM('Table'[value]),FILTER(ALL('Table'),'Table'[Year]=MAX('Table'[Year])&&'Table'[Date]<=MAX('Table'[Date])))
var _21=
CALCULATE (SUM ( [value] ),FILTER ( ALLEXCEPT ( 'Table', 'Table'[MMM] ), [Year] = 2021 ))
var _20=
CALCULATE (SUM ( [value] ),FILTER ( ALLEXCEPT ( 'Table', 'Table'[MMM] ), [Year] = 2020 ))
return
IF (
ISINSCOPE ( 'Table'[Year] ),
_cumulative,
IF(HASONEVALUE('Table'[MMM]),IF(ISBLANK(_21),BLANK(),_c21-_c20),_21-_20)
)
Sample:
Result:
Please refer to the attachment below for details. Hope this helps.
Best Regards,
Community Support Team _ Zeon Zheng
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Hi, @Orstenpowers
To create a measure like this:
_total =
var _21=
CALCULATE (
SUM ( [value] ),
FILTER ( ALLEXCEPT ( 'Table', 'Table'[MMM] ), [Year] = 2021 )
)
var _20=
CALCULATE (
SUM ( [value] ),
FILTER ( ALLEXCEPT ( 'Table', 'Table'[MMM] ), [Year] = 2020 )
)
return
IF (
ISINSCOPE ( 'Table'[Year] ),
SUM ( [value] ),
IF(ISBLANK(_21),_20,_21-_20)
)
Cumulative figures:
Cumulative figures =
var _c21=
CALCULATE(SUM('Table'[value]),FILTER(ALL('Table'),'Table'[Year]=2021&&'Table'[Date]<=MAX('Table'[Date])))
var _c20=
CALCULATE(SUM('Table'[value]),FILTER(ALL('Table'),'Table'[Year]=2020&&MONTH('Table'[Date])<=MONTH(MAX('Table'[Date]))))
var _cumulative=
CALCULATE(SUM('Table'[value]),FILTER(ALL('Table'),'Table'[Year]=MAX('Table'[Year])&&'Table'[Date]<=MAX('Table'[Date])))
var _21=
CALCULATE (SUM ( [value] ),FILTER ( ALLEXCEPT ( 'Table', 'Table'[MMM] ), [Year] = 2021 ))
var _20=
CALCULATE (SUM ( [value] ),FILTER ( ALLEXCEPT ( 'Table', 'Table'[MMM] ), [Year] = 2020 ))
return
IF (
ISINSCOPE ( 'Table'[Year] ),
_cumulative,
IF(HASONEVALUE('Table'[MMM]),IF(ISBLANK(_21),BLANK(),_c21-_c20),_21-_20)
)
Sample:
Result:
Please refer to the attachment below for details. Hope this helps.
Best Regards,
Community Support Team _ Zeon Zheng
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
@Orstenpowers , you have to use isinscope to switch total with diff ,
refer My example, I have used date table and time intelligence
Diff = if(not(isinscope(Date[Year])), SUM(Sales[Sales Amount]) - Year behind Sales = CALCULATE(SUM(Sales[Sales Amount]),dateadd('Date'[Date],-1,Year)) ,SUM(Sales[Sales Amount]))
To get the best of the time intelligence function. Make sure you have a date calendar and it has been marked as the date in model view. Also, join it with the date column of your fact/s. Refer :radacad sqlbi My Video Series Appreciate your Kudos.
Thanks for your feedback!
What do you mean with "My example"? 🤔
The formula you mentioned, this is a measure?
User | Count |
---|---|
134 | |
70 | |
69 | |
54 | |
52 |
User | Count |
---|---|
205 | |
95 | |
62 | |
61 | |
55 |