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

Earn a 50% discount on the DP-600 certification exam by completing the Fabric 30 Days to Learn It challenge.

Reply
soft5
Frequent Visitor

Need help with DAX

Hello, 

Please, please , someone help me with the following:

I have data set ( sample below)

Task is to count:

1. How many invoices were closed comparing to previous date ( don't appear next day)

2. How many changed status compared to previous date

3.How many haven't changed the status from last date

4. How many are new, so appear only on latest day

 

CompanyINVOICE_IDStatusDate
A22ac6open4/6/2023
A79065in progress4/6/2023
B70050failed4/6/2023
A80856open4/6/2023
Be42f6in progress4/6/2023
Bcba98failed4/6/2023
A22ac6open4/7/2023
A79065in progress4/7/2023
B70050failed4/7/2023
A80856open4/7/2023
Be42f6in progress4/7/2023
Bcba98failed4/7/2023
B4987aopen4/7/2023
Ce0ad7in progress4/7/2023
A3c3dcfailed4/7/2023
C9c40eopen4/7/2023
D47163in progress4/7/2023
D1a040failed4/7/2023
B467ccopen4/7/2023
A83ab5in progress4/7/2023
Ad7b17failed4/7/2023
A03681open4/7/2023
A79065in progress4/11/2023
A80856failed4/11/2023
Be42f6open4/11/2023
Bcba98in progress4/11/2023
B4987afailed4/11/2023
A3c3dcopen4/11/2023
C9c40ein progress4/11/2023
D47163failed4/11/2023
D1a040open4/11/2023
B467ccin progress4/11/2023
A83ab5failed4/11/2023
Ad7b17open4/11/2023
A03681in progress4/11/2023
Cbcaeffailed4/11/2023
A5eefdopen4/11/2023
C5eefdin progress4/11/2023
Df7a73failed4/11/2023
1 ACCEPTED SOLUTION

Hi , @soft5 

Thanks for your quick response!

Here are the steps you can refer to :
(1)My test data is the same as yours.

(2)We canc reate four measures to meet your need :

First Need = var _cur_date = MAX('Table'[Date])
var _pre_date = MAXX( FILTER( ALL('Table')  , 'Table'[Date]<_cur_date) ,[Date])
var _cur_list  = VALUES('Table'[INVOICE_ID])
var _pre_list = SELECTCOLUMNS( FILTER( ALL('Table') , 'Table'[Date] = _pre_date) , "invoices" , [INVOICE_ID])
var _list = EXCEPT(_pre_list , _cur_list)
return
COUNTROWS(_list)+0
Second Need = var _cur_date = MAX('Table'[Date])
var _pre_date = MAXX( FILTER( ALL('Table')  , 'Table'[Date]<_cur_date) ,[Date])
var _cur_list  = VALUES('Table'[INVOICE_ID])
var _pre_list = SELECTCOLUMNS( FILTER( ALL('Table') , 'Table'[Date] = _pre_date) , "invoices" , [INVOICE_ID])
var _same_list =  INTERSECT(_cur_list , _pre_list)
var _t = FILTER( ALL('Table') , 'Table'[INVOICE_ID] in _same_list && OR( 'Table'[Date] = _cur_date  , 'Table'[Date] =_pre_date) ) 
var _t2 =  ADDCOLUMNS( _t , "flag" ,  var _cur_in =[INVOICE_ID] var _count = COUNTROWS(DISTINCT(SELECTCOLUMNS( FILTER(_t , [INVOICE_ID] = _cur_in),"status" , [Status]))) return 
IF(_count>1 ,1,0))
return
SUMX(_t2, [flag])/2
Third Need = var _cur_date = MAX('Table'[Date])
var _pre_date = MAXX( FILTER( ALL('Table')  , 'Table'[Date]<_cur_date) ,[Date])
var _cur_list  = VALUES('Table'[INVOICE_ID])
var _pre_list = SELECTCOLUMNS( FILTER( ALL('Table') , 'Table'[Date] = _pre_date) , "invoices" , [INVOICE_ID])
var _same_list =  INTERSECT(_cur_list , _pre_list)
var _t = FILTER( ALL('Table') , 'Table'[INVOICE_ID] in _same_list && OR( 'Table'[Date] = _cur_date  , 'Table'[Date] =_pre_date) ) 
var _t2 =  ADDCOLUMNS( _t , "flag" ,  var _cur_in =[INVOICE_ID] var _count = COUNTROWS(DISTINCT(SELECTCOLUMNS( FILTER(_t , [INVOICE_ID] = _cur_in),"status" , [Status]))) return 
IF(_count=1 ,1,0))
return
SUMX(_t2, [flag])/2
Four Need = var _cur_date = MAX('Table'[Date])
var _cur_list  = VALUES('Table'[INVOICE_ID])
var _t  = SELECTCOLUMNS( FILTER( ALL('Table')  ,'Table'[Date]<_cur_date) , "invoices" , [INVOICE_ID])
var _t2 =  EXCEPT(_cur_list , _t)
return
countrows(_t2)

 

Then we can meet your need , the result is as follows:

vyueyunzhmsft_0-1681728114984.png

 

 

Thank you for your time and sharing, and thank you for your support and understanding of PowerBI! 

 

Best Regards,

Aniya Zhang

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

4 REPLIES 4
soft5
Frequent Visitor

Hello Aniya, 

 

Thank you for responding and willingness to help

Claryfying your questions:

1.  I need to count the invoices that have record on previous day and the following day those are not on the list. There should be distinct count of each record so for example for 4/11/2023 the resluft should be 3 - 

22ac6
70050
e0ad7

 

2 Yes it would be great to calculate it rolling, so shown for particular day - status change vs previous day

3. Ie ID 80856 

CompanyINVOICE_IDStatusDate
A80856open4/6/2023
A80856open4/7/2023
A80856failed4/11/2023
 

For 4/11/2023 this ID should count under status changed ( vs 4/7/2023)

For 4/7/2023 this ID should count under status unchanged ( vs 4/6/2023)

 

4. Distinct Count of IDs that haven't occured earlier than selected day. IE for 4/11/2023

the result is 3:

5eefd  2
bcaef  1
f7a73  1

 

I hope it helps.

 

Kind Regards

 

Hi , @soft5 

Thanks for your quick response!

Here are the steps you can refer to :
(1)My test data is the same as yours.

(2)We canc reate four measures to meet your need :

First Need = var _cur_date = MAX('Table'[Date])
var _pre_date = MAXX( FILTER( ALL('Table')  , 'Table'[Date]<_cur_date) ,[Date])
var _cur_list  = VALUES('Table'[INVOICE_ID])
var _pre_list = SELECTCOLUMNS( FILTER( ALL('Table') , 'Table'[Date] = _pre_date) , "invoices" , [INVOICE_ID])
var _list = EXCEPT(_pre_list , _cur_list)
return
COUNTROWS(_list)+0
Second Need = var _cur_date = MAX('Table'[Date])
var _pre_date = MAXX( FILTER( ALL('Table')  , 'Table'[Date]<_cur_date) ,[Date])
var _cur_list  = VALUES('Table'[INVOICE_ID])
var _pre_list = SELECTCOLUMNS( FILTER( ALL('Table') , 'Table'[Date] = _pre_date) , "invoices" , [INVOICE_ID])
var _same_list =  INTERSECT(_cur_list , _pre_list)
var _t = FILTER( ALL('Table') , 'Table'[INVOICE_ID] in _same_list && OR( 'Table'[Date] = _cur_date  , 'Table'[Date] =_pre_date) ) 
var _t2 =  ADDCOLUMNS( _t , "flag" ,  var _cur_in =[INVOICE_ID] var _count = COUNTROWS(DISTINCT(SELECTCOLUMNS( FILTER(_t , [INVOICE_ID] = _cur_in),"status" , [Status]))) return 
IF(_count>1 ,1,0))
return
SUMX(_t2, [flag])/2
Third Need = var _cur_date = MAX('Table'[Date])
var _pre_date = MAXX( FILTER( ALL('Table')  , 'Table'[Date]<_cur_date) ,[Date])
var _cur_list  = VALUES('Table'[INVOICE_ID])
var _pre_list = SELECTCOLUMNS( FILTER( ALL('Table') , 'Table'[Date] = _pre_date) , "invoices" , [INVOICE_ID])
var _same_list =  INTERSECT(_cur_list , _pre_list)
var _t = FILTER( ALL('Table') , 'Table'[INVOICE_ID] in _same_list && OR( 'Table'[Date] = _cur_date  , 'Table'[Date] =_pre_date) ) 
var _t2 =  ADDCOLUMNS( _t , "flag" ,  var _cur_in =[INVOICE_ID] var _count = COUNTROWS(DISTINCT(SELECTCOLUMNS( FILTER(_t , [INVOICE_ID] = _cur_in),"status" , [Status]))) return 
IF(_count=1 ,1,0))
return
SUMX(_t2, [flag])/2
Four Need = var _cur_date = MAX('Table'[Date])
var _cur_list  = VALUES('Table'[INVOICE_ID])
var _t  = SELECTCOLUMNS( FILTER( ALL('Table')  ,'Table'[Date]<_cur_date) , "invoices" , [INVOICE_ID])
var _t2 =  EXCEPT(_cur_list , _t)
return
countrows(_t2)

 

Then we can meet your need , the result is as follows:

vyueyunzhmsft_0-1681728114984.png

 

 

Thank you for your time and sharing, and thank you for your support and understanding of PowerBI! 

 

Best Regards,

Aniya Zhang

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

Hello Aniya, 

Thank you very much for sharing the query. It looks very promising. I like the logic of this solution. I still need to verify if it works for the full data set- and check if any adjustments are necessary.

v-yueyunzh-msft
Community Support
Community Support

Hi , @soft5 

According to your description, you want to count four tasks.

First of all, thank you very much for the test data,But I have a few questions about your needs.

1. How many invoices were closed comparing to previous date ( don't appear next day)

In your test data, you can see that invoices can be repeated, so what are the conditions for starting the calculation?How can I tell if the status of this invoices is closed? How is it calculated if there are multiple closed invoices?

 

2. How many changed status compared to previous date

This is the number of invoices that changed state the previous day, whether this is calculated daily or today?

 

3.How many haven't changed the status from last date

What is the specific logic of last date, each invoice has a different last date?

 

4. How many are new, so appear only on latest day.

How can I tell if it's new? How to determine the latest day, whether it is the most recent date or today?

 

You can also provide us with the final result you want in the form of a table, and describe your calculation logic in detail.Thanks in advance!

 

Thank you for your time and sharing, and thank you for your support and understanding of PowerBI! 

 

Best Regards,

Aniya Zhang

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

 

Helpful resources

Announcements
LearnSurvey

Fabric certifications survey

Certification feedback opportunity for the community.

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.