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
BeIntel
Frequent Visitor

Tickets Aging at the End of Particular Month

Hello All,

 

I am trying to create a report, where I'd like to show the total count of open tickets (backlogs) at the end of each month irrespective of current status as shown below:

 

New Date for Aging - If the ticket hasn't been resolved, eomonth date is considered for calculating Backlog age else resolved date is considered. I have put a sample data below to explain the scenario better. Please check and let me know, if you require any additional info.

 

Is there an easy way to find out the backlog age instead of creating new 6 columns to find the backlog age?

 

Ticket KeyCreated DateResolved DateEOM (based on created date)New Date for AgingAging on eom Jul 23New Date for AgingAging on eom Aug 23New Date for AgingAging  on eom Sep 23
CC105-Jul-2302-Oct-2331-Jul-2331-Jul-232631-Aug-235730-Sep-2387
CC205-Jul-23 31-Jul-2331-Jul-232631-Aug-235730-Sep-2387
CC305-Jul-23 31-Jul-2331-Jul-232631-Aug-235730-Sep-2387
AB101-Aug-2301-Aug-2331-Aug-23  01-Aug-23001-Aug-230
AB201-Aug-2305-Sep-2331-Aug-23  31-Aug-233105-Sep-2336
AB301-Aug-2301-Aug-2331-Aug-23  01-Aug-23001-Aug-230
AB401-Aug-23 31-Aug-23  31-Aug-233130-Sep-2361
AB502-Sep-2302-Sep-2330-Sep-23    02-Sep-230
AB602-Sep-2302-Sep-2330-Sep-23    02-Sep-230
AB702-Sep-2302-Oct-2330-Sep-23    30-Sep-2328
1 ACCEPTED SOLUTION
v-xinruzhu-msft
Community Support
Community Support

Hi @BeIntel 

You can create a date table

e.g 

Table 2 = CALENDAR(DATE(2023,1,1),DATE(2023,12,31))

Then create a measure

Measure =
IF (
    SELECTEDVALUE ( 'Table'[Resolved Date] ) <> BLANK (),
    IF (
        MAX ( 'Table 2'[Date] ) >= SELECTEDVALUE ( 'Table'[Created Date] )
            && MAX ( 'Table 2'[Date] ) < SELECTEDVALUE ( 'Table'[Resolved Date] ),
        DATEDIFF (
            SELECTEDVALUE ( 'Table'[Created Date] ),
            EOMONTH ( MAX ( 'Table 2'[Date] ), 0 ),
            DAY
        ),
        IF (
            EOMONTH ( MAX ( 'Table 2'[Date] ), 0 )
                = EOMONTH ( SELECTEDVALUE ( 'Table'[Resolved Date] ), 0 ),
            DATEDIFF (
                SELECTEDVALUE ( 'Table'[Created Date] ),
                SELECTEDVALUE ( 'Table'[Resolved Date] ),
                DAY
            )
        )
    ),
    IF (
        MAX ( 'Table 2'[Date] ) >= SELECTEDVALUE ( 'Table'[Created Date] )
            && MAX ( 'Table 2'[Date] ) <= MAXX ( ALLSELECTED ( 'Table 2' ), [Date] ),
        DATEDIFF (
            SELECTEDVALUE ( 'Table'[Created Date] ),
            EOMONTH ( MAX ( 'Table 2'[Date] ), 0 ),
            DAY
        )
    )
)

Then create a table visual, and and put the date column and ticket key and measure to it.

Output

vxinruzhumsft_0-1697608501825.png

Best Regards!

Yolo Zhu

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

 

View solution in original post

1 REPLY 1
v-xinruzhu-msft
Community Support
Community Support

Hi @BeIntel 

You can create a date table

e.g 

Table 2 = CALENDAR(DATE(2023,1,1),DATE(2023,12,31))

Then create a measure

Measure =
IF (
    SELECTEDVALUE ( 'Table'[Resolved Date] ) <> BLANK (),
    IF (
        MAX ( 'Table 2'[Date] ) >= SELECTEDVALUE ( 'Table'[Created Date] )
            && MAX ( 'Table 2'[Date] ) < SELECTEDVALUE ( 'Table'[Resolved Date] ),
        DATEDIFF (
            SELECTEDVALUE ( 'Table'[Created Date] ),
            EOMONTH ( MAX ( 'Table 2'[Date] ), 0 ),
            DAY
        ),
        IF (
            EOMONTH ( MAX ( 'Table 2'[Date] ), 0 )
                = EOMONTH ( SELECTEDVALUE ( 'Table'[Resolved Date] ), 0 ),
            DATEDIFF (
                SELECTEDVALUE ( 'Table'[Created Date] ),
                SELECTEDVALUE ( 'Table'[Resolved Date] ),
                DAY
            )
        )
    ),
    IF (
        MAX ( 'Table 2'[Date] ) >= SELECTEDVALUE ( 'Table'[Created Date] )
            && MAX ( 'Table 2'[Date] ) <= MAXX ( ALLSELECTED ( 'Table 2' ), [Date] ),
        DATEDIFF (
            SELECTEDVALUE ( 'Table'[Created Date] ),
            EOMONTH ( MAX ( 'Table 2'[Date] ), 0 ),
            DAY
        )
    )
)

Then create a table visual, and and put the date column and ticket key and measure to it.

Output

vxinruzhumsft_0-1697608501825.png

Best Regards!

Yolo Zhu

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

 

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.