cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
negarabi
Frequent Visitor

Creating the DAX formula to use the previous value in the other column

Hello everyone

I'm trying to create the backlog column as follows:

Backlog (OpenTicket + pre_week to backlog)- CloseTicket

I know that the delay 2 per week (24 Feb - 1 Sea )

DateOpenTicketCloseTicketDelay
02-08 Mar525
09-15 Mar436
16 -22 Mar6210

Could someone else give me a solution to this? It would help me a lot.

Thank you in advance,

1 ACCEPTED SOLUTION
v-lid-msft
Community Support
Community Support

Hello @negarabi ,

If OpenTicket and CloseTicket are measured and shown in the table visual, the @amitchandak solution is great and will work fine.

(when you create the measure, try using FILTER(ALLSELECTED('Date'),......) instead of FILTER('Date',......) )

But if the raw table looks like, as [Date] column is text, we can create a calculated column to get the first date this week

First Date =
VAR MonthTable =
    ADDCOLUMNS (
        GENERATESERIES ( 1, 12 ),
        "MonthName", FORMAT ( DATE ( 2000, [Value], 1 ), "MMM" )
    )
RETURN
    DATE ( 2020, MAXX ( FILTER ( MonthTable, [MonthName] = RIGHT ( [Date], 3 ) ), [Value] ), VALUE ( LEFT ( [Date], 2 ) ) )

you can beat 2020 as your year column

Next, we can create another calculation column, use the sum function if the Openticket is a column instead measure, to get the desired result:

Back Log =
VAR currentDate = [First Date]
RETURN
    2
        + CALCULATE (
            SUM ( 'Table'[OpenTicket] ) - SUM ( 'Table'[CloseTicket] ),
            'Table',
            'Table'[First Date] <= currentDate
        )

1.jpg


By the way, pbIX file as attachment.


Best regards

Community Support Team _ Dong Li
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

3 REPLIES 3
v-lid-msft
Community Support
Community Support

Hi @negarabi ,

 

How about the result after you follow the suggestions mentioned in my original post?Could you please provide more details about it If it doesn't meet your requirement?


Best regards,

Community Support Team _ Dong Li
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
v-lid-msft
Community Support
Community Support

Hello @negarabi ,

If OpenTicket and CloseTicket are measured and shown in the table visual, the @amitchandak solution is great and will work fine.

(when you create the measure, try using FILTER(ALLSELECTED('Date'),......) instead of FILTER('Date',......) )

But if the raw table looks like, as [Date] column is text, we can create a calculated column to get the first date this week

First Date =
VAR MonthTable =
    ADDCOLUMNS (
        GENERATESERIES ( 1, 12 ),
        "MonthName", FORMAT ( DATE ( 2000, [Value], 1 ), "MMM" )
    )
RETURN
    DATE ( 2020, MAXX ( FILTER ( MonthTable, [MonthName] = RIGHT ( [Date], 3 ) ), [Value] ), VALUE ( LEFT ( [Date], 2 ) ) )

you can beat 2020 as your year column

Next, we can create another calculation column, use the sum function if the Openticket is a column instead measure, to get the desired result:

Back Log =
VAR currentDate = [First Date]
RETURN
    2
        + CALCULATE (
            SUM ( 'Table'[OpenTicket] ) - SUM ( 'Table'[CloseTicket] ),
            'Table',
            'Table'[First Date] <= currentDate
        )

1.jpg


By the way, pbIX file as attachment.


Best regards

Community Support Team _ Dong Li
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

amitchandak
Super User IV
Super User IV

@negarabi , you have to build it using open and close

 

Cumm Sales = CALCULATE([OPen]-[Close],filter(date,date[date] <=maxx(date,date[date])))
Cumm Sales = CALCULATE([OPen]-[Close],,filter(date,date[date] <=max(Sales[Sales Date])))

 

Or use week Rank, if you do not have Dates

Assume Week table is Date

Cumm Sales = CALCULATE([OPen]-[Close],filter(date,date[Week Rank] <=maxx(date,date[Week Rank])))

How to do

https://community.powerbi.com/t5/Webinars-and-Video-Gallery/PowerBI-Time-Intelligence-Calendar-WTD-Y...



Did I answer your question? Mark my post as a solution! Appreciate your Kudos!!
Dashboard of My Blogs !! YouTube Channel !! Connect on Linkedin

Proud to be a Super User!

Helpful resources

Announcements
PBI User Groups

Welcome to the User Group Public Preview

Check out new user group experience and if you are a leader please create your group!

MBAS on Demand

Microsoft Business Applications Summit sessions

On-demand access to all the great content presented by the product teams and community members! #MSBizAppsSummit #CommunityRocks

Get Ready for Power BI Dev Camp

Power BI Dev Camp - June 24th

Mark your calendars and join us for our next Power BI Dev Camp!

Top Solution Authors
Top Kudoed Authors