March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Early bird discount ends December 31.
Register NowBe one of the first to start using Fabric Databases. View on-demand sessions with database experts and the Microsoft product team to learn just how easy it is to get started. Watch now
Hi All,
Can someone please help me to write DAX to calculate the total distict count of Zero Balance Accounts based on below mentioned logic :-
Logic Defintion : For a particular Account Number , the YTD Balance should be equal to = 0 in all the years i.e 2018,2019,2020 (not any of the two or one specific year). YTD Balance should be 0 for 2018 AND 2019 AND 2020. If for a account this is true then it would be counted as one.
Logic should be something like this Considering Account number : 10154
Condition 1 --> Account 10154 : YTD Balance = 0 AND Year=2018
Condition 2 -->Account 10154 : YTD Balance = 0 AND Year=2019
Condition 3 -->Account 10154 : YTD Balance = 0 AND Year=2020
If all three conditions are true then count should be taken as one. Similarly this DAX Measure should COUNT all other Accounts where this above condition is met. Example shown below :-
NOTE : One account can have transactions under multiple companies as well . This needs to be considered while designing the desired DAX . In above screenshot Account : 10154 is having transaction under only one Company . But there are chances that one account is having transaction under multiple Companies such as 8000, etc.
So this is required to be calculated for all the Accounts in the Dataset attached as mentioned below :-
Thanks & Regards,
Ashish Sharma
Solved! Go to Solution.
Hi @Anonymous ,
We can create a measure and add a card visual to meet your requirement.
distict count of Accounts =
CALCULATE (
DISTINCTCOUNT ( 'Table'[account] ),
FILTER (
SUMMARIZE (
FILTER (
'Table',
'Table'[year] = 2018
|| 'Table'[year] = 2019
|| 'Table'[year] = 2020
),
'Table'[account],
"YTD_total", CALCULATE ( SUM ( 'Table'[YTD] ) )
),
[YTD_total] = 0
)
)
If it doesn’t meet your requirement, could you please show the exact expected result based on the table that you have shared?
BTW, pbix as attached.
Best regards,
Community Support Team _ zhenbw
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
@Anonymous
Please see if the below solution can help you.
1. create a column.
2. Use below DAX coding
testing = iF(SUMX(FILTER('table','table'[account]=EARLIER('table'[account])),'table'[YTD balance])=0,'table'[account],'table'[account]&'table'[year])
Thanks and BR
Ryan
Proud to be a Super User!
Hi @Anonymous ,
We can create a measure and add a card visual to meet your requirement.
distict count of Accounts =
CALCULATE (
DISTINCTCOUNT ( 'Table'[account] ),
FILTER (
SUMMARIZE (
FILTER (
'Table',
'Table'[year] = 2018
|| 'Table'[year] = 2019
|| 'Table'[year] = 2020
),
'Table'[account],
"YTD_total", CALCULATE ( SUM ( 'Table'[YTD] ) )
),
[YTD_total] = 0
)
)
If it doesn’t meet your requirement, could you please show the exact expected result based on the table that you have shared?
BTW, pbix as attached.
Best regards,
Community Support Team _ zhenbw
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!
User | Count |
---|---|
90 | |
89 | |
85 | |
73 | |
49 |
User | Count |
---|---|
167 | |
147 | |
92 | |
70 | |
58 |