March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Early bird discount ends December 31.
Register NowBe one of the first to start using Fabric Databases. View on-demand sessions with database experts and the Microsoft product team to learn just how easy it is to get started. Watch now
Hi - I do have a Power BI model with ShipDateKey (Active) and OrderDateKey (Inactive) for fct Sales joined with DimCalendar. I am looking for a DAX calculation that gives me SUM of GrossPrice where ShipDateKey is Current Month ( Jan 2021) AND Order Date is (Dec 2020).
I also have DimCalendar with Column RelativeMonth (-1,0,1) as 0 Previous Month and 1 as Current Month.
The SQL for the calculation should be like this.
SELECT SUM([Gross Price]) GP
FROM [DW].[dbo].[v_fctSales]
WHERE OrderDateKey LIKE '202012__' AND ShipDateKey LIKE '202101__'
Solved! Go to Solution.
Measure =
VAR Y1_ = YEAR ( TODAY () )
VAR M1_ = MONTH ( TODAY () )
VAR Y0_ = YEAR ( EDATE ( TODAY (), -1 ) )
VAR M0_ = MONTH ( EDATE ( TODAY (), -1 ) )
RETURN
CALCULATE (
SUM ( Sales[Gross Price] ),
YEAR ( Sales[ShipDateKey] ) = Y1_,
MONTH ( Sales[ShipDateKey] ) = M1_,
YEAR ( Sales[OrderDate] ) = Y0_,
MONTH ( Sales[OrderDate] ) = M0_
)
Please mark the question solved when done and consider giving a thumbs up if posts are helpful.
Contact me privately for support with any larger-scale BI needs, tutoring, etc.
Cheers
Measure =
VAR Y1_ = YEAR ( TODAY () )
VAR M1_ = MONTH ( TODAY () )
VAR Y0_ = YEAR ( EDATE ( TODAY (), -1 ) )
VAR M0_ = MONTH ( EDATE ( TODAY (), -1 ) )
RETURN
CALCULATE (
SUM ( Sales[Gross Price] ),
YEAR ( Sales[ShipDateKey] ) = Y1_,
MONTH ( Sales[ShipDateKey] ) = M1_,
YEAR ( Sales[OrderDate] ) = Y0_,
MONTH ( Sales[OrderDate] ) = M0_
)
Please mark the question solved when done and consider giving a thumbs up if posts are helpful.
Contact me privately for support with any larger-scale BI needs, tutoring, etc.
Cheers
Hi @hitesh1607
Measure =
CALCULATE (
SUM ( Sales[Gross Price] ),
YEAR ( Sales[ShipDateKey] ) = 2021,
MONTH ( Sales[ShipDateKey] ) = 1,
YEAR ( Sales[OrderDate] ) = 2020,
MONTH ( Sales[OrderDate] ) = 12
)
Please mark the question solved when done and consider giving a thumbs up if posts are helpful.
Contact me privately for support with any larger-scale BI needs, tutoring, etc.
Cheers
Hi @AlB - This way my DAX will become static and I need a dynamic solution that can determine the Current Month for the Ship date and the previous month for the Order Date. Is there a way we can write a DAX using relative Calendar month ?? I Do have that in my dimCalendar and it changes dynamically.
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!
Your insights matter. That’s why we created a quick survey to learn about your experience finding answers to technical questions.
Arun Ulag shares exciting details about the Microsoft Fabric Conference 2025, which will be held in Las Vegas, NV.
User | Count |
---|---|
134 | |
91 | |
89 | |
64 | |
58 |
User | Count |
---|---|
201 | |
137 | |
107 | |
72 | |
68 |