Skip to main content
cancel
Showing results for 
Search instead for 
Did you mean: 

Join 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.

Reply
OldDinosaur79
Frequent Visitor

Using Hierarchy Date - Totalling issue

I am completely new to Power BI and have a query that works out Incoming by looking at (Open in Day + Closed in Day) minus Open from previous day (see DAX below).

The issue I have is when using the date hierarchy at a daily level my volumes are correct but the monthly and yearly totals are incorrect.  


Any help would be appreciated

 

--Get Open and Closed

VAR CurrentOpen =

Calculate(SUM(Table[Volume]),Table[Process] = "Open")

 

VAR CurrentClosed =

Calculate(SUM(Table[Volume]),Table[Process] = "Closed")

 

-- Previous Day Open

VAR PreviousOpen =

VAR latestdate = max(dim_calender[Date])

VAR previousdate = Calculate(max(dim_calender[Date]),dim_calender[Date])<latestdate)

 

return Calculate(sum(Table[volume]),dim_calender[Date]=previousdate,table[Process]="Open")

 

--Calculate Volume

Return

(CurrentOpen+CurrentClosed)-PreviousOpen

 

1 ACCEPTED SOLUTION
DataZoe
Microsoft Employee
Microsoft Employee

Hi @OldDinosaur79 

 

I could not get your measure to work as you had pasted it, but depending on how you are trying to see it aggregated by your date hierarchy, you may need to use SUMX, MINX, MAXX, or AVERAGEX. These will perform the calculation at the daily level then sum, min, max, or average the daily calculation to other date periods. 

 

Here is a measure I got working that will rollup the daily number as a sum for month, quarter, year, etc.

 

 

Incoming = 
        // The measure adds the volumes for "Open" and "Closed" processes and subtracts the volume for "Open" processes from the previous day.
        // SUMX dim_calendar will do the daily calculation then sum it by other periods (month, quarter, year). 
        // You can also use MINX (lowest incoming that period), MAXX (highest incoming that period), or AVERAGEX (average incoming that period)
        SUMX(
			dim_calender,
			CALCULATE(
				SUM('Table'[Volume]),
				'Table'[Process] = "Open"
			) +
			CALCULATE(
				SUM('Table'[Volume]),
				'Table'[Process] = "Closed"
			)
			- CALCULATE(
				SUM('Table'[Volume]),
				'Table'[Process] = "Open",
				PREVIOUSDAY(dim_calender[Date])
			)
		)

 

 

More information about SUMX: SUMX function (DAX) - DAX | Microsoft Learn

 

Respectfully,
Zoe Douglas (DataZoe)



Follow me on LinkedIn at https://www.linkedin.com/in/zoedouglas-data
See my reports and blog at https://www.datazoepowerbi.com/

View solution in original post

3 REPLIES 3
Anonymous
Not applicable

Thanks for the reply from DataZoe.

 

Hi @OldDinosaur79 ,

 

Did DataZoe's solution resolve your issue? Based on my tests, it seems to work correctly at each hierarchy level.

vlinhuizhmsft_0-1740460362679.png

Additionally, you can create another measure on top of the existing one:

Measure  = SUMX(VALUES('dim_calender'[Date]),'Table'[YourMeasure])

Let me know if you need any further assistance!

 

Best Regards,
Zhu

 

If there is any post helps, then please consider Accept it as the solution  to help the other members find it more quickly.

Thank you @Anonymous @DataZoe . 

really useful 

DataZoe
Microsoft Employee
Microsoft Employee

Hi @OldDinosaur79 

 

I could not get your measure to work as you had pasted it, but depending on how you are trying to see it aggregated by your date hierarchy, you may need to use SUMX, MINX, MAXX, or AVERAGEX. These will perform the calculation at the daily level then sum, min, max, or average the daily calculation to other date periods. 

 

Here is a measure I got working that will rollup the daily number as a sum for month, quarter, year, etc.

 

 

Incoming = 
        // The measure adds the volumes for "Open" and "Closed" processes and subtracts the volume for "Open" processes from the previous day.
        // SUMX dim_calendar will do the daily calculation then sum it by other periods (month, quarter, year). 
        // You can also use MINX (lowest incoming that period), MAXX (highest incoming that period), or AVERAGEX (average incoming that period)
        SUMX(
			dim_calender,
			CALCULATE(
				SUM('Table'[Volume]),
				'Table'[Process] = "Open"
			) +
			CALCULATE(
				SUM('Table'[Volume]),
				'Table'[Process] = "Closed"
			)
			- CALCULATE(
				SUM('Table'[Volume]),
				'Table'[Process] = "Open",
				PREVIOUSDAY(dim_calender[Date])
			)
		)

 

 

More information about SUMX: SUMX function (DAX) - DAX | Microsoft Learn

 

Respectfully,
Zoe Douglas (DataZoe)



Follow me on LinkedIn at https://www.linkedin.com/in/zoedouglas-data
See my reports and blog at https://www.datazoepowerbi.com/

Helpful resources

Announcements
Join our Fabric User Panel

Join our Fabric User Panel

This is your chance to engage directly with the engineering team behind Fabric and Power BI. Share your experiences and shape the future.

June 2025 Power BI Update Carousel

Power BI Monthly Update - June 2025

Check out the June 2025 Power BI update to learn about new features.

June 2025 community update carousel

Fabric Community Update - June 2025

Find out what's new and trending in the Fabric community.