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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
cmarrazzo
Frequent Visitor

Creating a running total using a measure and multiple date columns

What I need to produce is a running total of open service tickets by week with the ability to filter by ticket type which is done so by the ticket owner. So my data set has two date columns, one for date entered and another for date closed. If the ticket is still open, the date closed column is empty. For example:

 

Ticket NumberTicket OwnerDate EnteredDate Closed
100000JDoe1/1/20221/5/2022
100001JDoe1/3/20221/6/2022
100002MSmith1/5/2022 
100003JDoe1/7/20221/10/2022
100004MSmith1/9/2022 
100005JDoe1/14/2022 


I have a date helper table to help associate the days to weeks, one of which is an inactive relationship. I have another employee table that associates employees (ticket owners) with the type of ticket. 

So I have been successful in determining count of ticket entries using this DAX to create a measure:

 

Ticket Entries =
CALCULATE(
    COUNTA('Tickets'[Date Entered]),
    ALLSELECTED('Date Helper Table'[Day])
)

And I have been successful in determining ticket closures by date using this DAX to create a measure: 

Ticket Closures =
CALCULATE(
    COUNTA('Tickets'[Date Closed]),
    ALLSELECTED('Date Helper Table'[Day]),
    USERELATIONSHIP(Tickets[Date Closed],'Date Helper Table'[Day])
)
 
I have been successful finding the weekly ticket backlog by using a DAX expression to find the weekly backlog by subtracting the count of ticket closures from count of weekly ticket entries. 
 
What I've been struggling with is finding a way to calculate a running total of ticket backlog by week while keeping it able to be filtered by employee. 
 
If it helps, here is what my date helper table looks like to group entries/closures/backlog by week:
 
cmarrazzo_0-1659976207499.png

 

Any help is appreciated!

1 ACCEPTED SOLUTION

Hi @cmarrazzo ,

 

Create a new calculated column to group the [Date Closed] field.

Week 2# = WEEKNUM('Tickets'[Date Closed],2)

Create a new measure that will be used later to determine what week it is in the current context.

Week = MAX('Table'[Week #])

Calculate the number of tickets closed for the week.

Current Week Ticket Closures = 
CALCULATE(
    COUNTA('Tickets'[Date Closed]),
    FILTER('Tickets','Tickets'[Week 2#]=[Week]),
    ALLSELECTED('Date Helper Table'[Day])
)

vcgaomsft_0-1661132998963.png

vcgaomsft_1-1661133513961.png

The PBIX file is attached for reference.

 

Best Regards,
Gao

Community Support Team

 

If there is any post helps, then please consider Accept it as the solution to help the other members find it more quickly. If I misunderstand your needs or you still have problems on it, please feel free to let us know. Thanks a lot!

How to get your questions answered quickly -- How to provide sample data

View solution in original post

5 REPLIES 5
amitchandak
Super User
Super User

@cmarrazzo , refer my HR blog or attached files after the signature of the similar problem

https://community.powerbi.com/t5/Community-Blog/HR-Analytics-Active-Employee-Hire-and-Termination-tr...

 

 

@amitchandak So I understand the logic of this, but the issue I'm still having is getting it by week since week is a somewhat non traditional date type in Power BI.

And will this keep in tact the ability to filter by employee dimensions?

Hi @cmarrazzo ,

 

1. If Week is added directly to Page as an external filter, it can be filtered correctly by week and employee.

vcgaomsft_0-1660809467259.png

2. If you consider starting with models and formulas, you also need to create a new [week] column in the 'Tickets' table, and since it is a many-to-many relationship with the [week #] column in the 'Date Helper Table', you also need to create a new bridge table between them to connect.

vcgaomsft_1-1660810353926.png

It can also be filtered by week and employee.

vcgaomsft_3-1660811150001.png

 

Reference:

Many-to-many relationship guidance

 

The PBIX file is attached for reference.

 

Best Regards,
Gao

Community Support Team

 

If there is any post helps, then please consider Accept it as the solution to help the other members find it more quickly. If I misunderstand your needs or you still have problems on it, please feel free to let us know. Thanks a lot!

How to get your questions answered quickly -- How to provide sample data

@v-cgao-msft The only issue with this method is it associates week # with date entered only for each row. So it counts number of tickets closed but doesn't count those in the appropriate week. 

Hi @cmarrazzo ,

 

Create a new calculated column to group the [Date Closed] field.

Week 2# = WEEKNUM('Tickets'[Date Closed],2)

Create a new measure that will be used later to determine what week it is in the current context.

Week = MAX('Table'[Week #])

Calculate the number of tickets closed for the week.

Current Week Ticket Closures = 
CALCULATE(
    COUNTA('Tickets'[Date Closed]),
    FILTER('Tickets','Tickets'[Week 2#]=[Week]),
    ALLSELECTED('Date Helper Table'[Day])
)

vcgaomsft_0-1661132998963.png

vcgaomsft_1-1661133513961.png

The PBIX file is attached for reference.

 

Best Regards,
Gao

Community Support Team

 

If there is any post helps, then please consider Accept it as the solution to help the other members find it more quickly. If I misunderstand your needs or you still have problems on it, please feel free to let us know. Thanks a lot!

How to get your questions answered quickly -- How to provide sample data

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

Check out the April 2024 Power BI update to learn about new features.

April Fabric Community Update

Fabric Community Update - April 2024

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

Top Solution Authors