cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
aj1107 Helper I
Helper I

DAX calculation max date and exclude data set

Im trying to create a line chart using below scenario.

 

Table

issueid ,status ,substatus ,cdate

1 ,closed ,mpv ,01/15/2017

1 ,closed ,xyz ,02/19/2017

1 ,open ,xyz ,04/12/2017

2 ,closed ,xyz , 03/12/2017

2 ,closed ,xyz , 05/12/2017

3 ,closed ,xyz ,01/28/2017

 

Scenario :

condition1 Exlude the entire issue id group <if status="open" or status="mpv"> and Condition2 distinctcount(issueid) based on max(cdate) for the issue id. Highlighted green is eligible count when aggregated at month level.

 

Result : 

Month, Issue

Jan17, 1

May17, 1

 

Solution : I was able to get the result by implementing the sceanrio at database level  or through DAX query by creating calculated table (condition1) and calculated column rankx function to identify the max date for each issueid(condition2) and finally claculated measure to include condition1 and codition2 :

calculate(distinctcount(issueid),filter(table,issueid<>related(calculatedtable) && maxdate=1)) 

 

Just want to check is there any scope to finetune the dax calculation. Any other alternate way to get the same result.

 

Thank you,

1 ACCEPTED SOLUTION

Accepted Solutions
Microsoft
Microsoft

Re: DAX calculation max date and exclude data set

Hi @aj1107

 

I had some success with this approach.  I created a new calcualted table using the following code

 

Table = 
VAR ExcludeThese = SUMMARIZE(FILTER('Table1','Table1'[status] ="Open" || Table1[substatus] = "mpv"),Table1[Issueid],"Blank",1)
VAR ReturnTable =SUMMARIZE(
            SUMMARIZE(
                FILTER(
                    NATURALLEFTOUTERJOIN(Table1,ExcludeThese),
                    [Blank] = blank()
                    ),
                    'Table1'[Issueid],"Max Date" ,
                    MAX('Table1'[cdate])
                    ),
                    [Max Date],
                    "Issue",
                    DISTINCTCOUNT(Table1[Issueid])
                    )
RETURN SELECTCOLUMNS(ReturnTable,"Month",FORMAT([Max Date],"MMMYY"),"Issue",[Issue])

To learn more about DAX visit : aka.ms/practicalDAX

Proud to be a Datanaut!

View solution in original post

1 REPLY 1
Microsoft
Microsoft

Re: DAX calculation max date and exclude data set

Hi @aj1107

 

I had some success with this approach.  I created a new calcualted table using the following code

 

Table = 
VAR ExcludeThese = SUMMARIZE(FILTER('Table1','Table1'[status] ="Open" || Table1[substatus] = "mpv"),Table1[Issueid],"Blank",1)
VAR ReturnTable =SUMMARIZE(
            SUMMARIZE(
                FILTER(
                    NATURALLEFTOUTERJOIN(Table1,ExcludeThese),
                    [Blank] = blank()
                    ),
                    'Table1'[Issueid],"Max Date" ,
                    MAX('Table1'[cdate])
                    ),
                    [Max Date],
                    "Issue",
                    DISTINCTCOUNT(Table1[Issueid])
                    )
RETURN SELECTCOLUMNS(ReturnTable,"Month",FORMAT([Max Date],"MMMYY"),"Issue",[Issue])

To learn more about DAX visit : aka.ms/practicalDAX

Proud to be a Datanaut!

View solution in original post

Helpful resources

Announcements
‘Better Together’ T-Shirt Contest – Winner Announced!

‘Better Together’ T-Shirt Contest – Winner Announced!

And the winner is...

Announcing the New Spanish Forum

Announcing the New Spanish Forum

Do you need help in Spanish? Check out our new Spanish community section.

April 2020 Community Highlights

April 2020 Community Highlights

Info on our Super Users, MBAS content and badges, and updates to our support articles. - Read the full Community Highlights.

MBAS Gallery 2020

MBAS Gallery 2020

Watch Microsoft Business Applications Summit sessions on-demand.

Top Solution Authors
Top Kudoed Authors