Starting December 3, join live sessions with database experts and the Microsoft product team to learn just how easy it is to get started
Learn moreGet certified in Microsoft Fabric—for free! For a limited time, get a free DP-600 exam voucher to use by the end of 2024. Register now
Hello. The Cumulative Balance pattern works well for me for trending Total Accounts Receivable. But I'm having trouble adapting it to subsets of the total (e.g., by account age group). Here is the normal pattern:
Solved! Go to Solution.
Unfortunately that did not work. But luckily I stumbled on a formula that works. Here it is in case anyone is interested. I'd be happy to hear any suggestions as to improvements to this formula if any exist.
Total AR 0-30 =
VAR EndDate =
MAX ( 'Calendar'[Date] )
RETURN
IF (
MIN ( 'Calendar'[Date] )
<= CALCULATE ( MAX ('TransactionsTable'[PostingDate]), ALL ('TransactionsTable') ),
CALCULATE (
SUM ( 'TransactionsTable'[TransactionAmount] ),
FILTER ( ALL ( 'Calendar'[Date] ), 'Calendar'[Date] <= EndDate ),
KEEPFILTERS (
IFERROR (
DATEDIFF ( CustomerTable[CustomerCheckoutDate], EndDate, DAY ),
( DATEDIFF ( EndDate, CustomerTable[CustomerCheckoutDate], DAY ) ) * -1
)
< 31
)
)
)
can you share anonymized sample rows for the tables used?
is 31 the only age group you cover, or are there others, if so, what are they?
Hello @Stachu. Thanks for your reply. Below is some sample data. I have a calendar table that is connected to the table below on the Transaction Date.
Ultimately I would want age groups for every 30 days up to 180 and then 180+. But I figured if I could get 0-30 figured out then I could take it from there to do the other buckets.
Account # | Item # | Transaction Date | Transaction Amount | CustomerCheckoutDate |
1 | 532555 | 3/14/2018 | $ 4,214.00 | 4/4/2018 |
1 | 134134 | 3/21/2018 | $ 1,354.00 | 4/4/2018 |
1 | 413443 | 2/6/2018 | $ 1,661.00 | 4/4/2018 |
1 | 412141 | 4/5/2018 | $ 1,838.00 | 4/4/2018 |
2 | 585811 | 2/13/2018 | $ 2,065.00 | 2/22/2018 |
2 | 147547 | 2/24/2018 | $ 4,238.00 | 2/22/2018 |
2 | 454787 | 2/9/2018 | $ 3,698.00 | 2/22/2018 |
hmm, can you try this?
LessThan31 = VAR DaysOverdue = ADDCOLUMNS ( Transactions, "DaysOverdue", Transactions[CustomerCheckoutDate] - Transactions[Transaction Date] ) VAR LessThan31 = FILTER ( DaysOverdue, [DaysOverdue] < 31 ) RETURN CALCULATE ( SUM ( Transactions[Transaction Amount] ), LessThan31 )
I wasn't clear whether you need to calculate the days on row level (current syntax) or grouped per Account/Account&Item, if grouping is possible then Summarize could replace whole Transactions table
Also the problem becones very easy once you add calculated column for
Transactions[CustomerCheckoutDate] - Transactions[Transaction Date]
the question is whether it makes sense from aggregation angle
Unfortunately that did not work. But luckily I stumbled on a formula that works. Here it is in case anyone is interested. I'd be happy to hear any suggestions as to improvements to this formula if any exist.
Total AR 0-30 =
VAR EndDate =
MAX ( 'Calendar'[Date] )
RETURN
IF (
MIN ( 'Calendar'[Date] )
<= CALCULATE ( MAX ('TransactionsTable'[PostingDate]), ALL ('TransactionsTable') ),
CALCULATE (
SUM ( 'TransactionsTable'[TransactionAmount] ),
FILTER ( ALL ( 'Calendar'[Date] ), 'Calendar'[Date] <= EndDate ),
KEEPFILTERS (
IFERROR (
DATEDIFF ( CustomerTable[CustomerCheckoutDate], EndDate, DAY ),
( DATEDIFF ( EndDate, CustomerTable[CustomerCheckoutDate], DAY ) ) * -1
)
< 31
)
)
)
Hi @robarivas,
Congratulations, please mark your reply as answer, so more people will benefit from here.
Thanks,
Angelia
Hi @robarivas,
Please use the following DAX and check if you can get expected result.
= VAR X = MAX ( 'Date'[Date] ) RETURN IF ( MIN ( 'Date'[Date] ) <= CALCULATE ( MAX ( TransactionsTable[Posting_Date] ), ALL ( TransactionsTable ) ) && DATEDIFF ( MAX ( TransactionsTable[CustomerCheckoutDate] ), 'Date'[Date], DAY ) < 31, CALCULATE ( SUM ( TransactionsTable[Transaction_Amount] ), FILTER ( ALL ( 'Date'[Date] ), 'Date'[Date] <= X ) ) )
Best Regards,
Angelia
Hello @v-huizhn-msft. Thank you for the reply. Unfortunately it kicked back the following error:
"A single value for column 'Date' in table 'Date' cannot be determined. This can happen when a measure formula refers to a column that contains many values without specifying an aggregation such as min, max, count, or sum to get a single result."
Below is the portion of the formula that appears to have caused the error:
= VAR X = MAX ( 'Date'[Date] ) RETURN IF ( MIN ( 'Date'[Date] ) <= CALCULATE ( MAX ( TransactionsTable[Posting_Date] ), ALL ( TransactionsTable ) ) && DATEDIFF ( MAX ( TransactionsTable[CustomerCheckoutDate] ), 'Date'[Date], DAY ) < 31, CALCULATE ( SUM ( TransactionsTable[Transaction_Amount] ), FILTER ( ALL ( 'Date'[Date] ), 'Date'[Date] <= X ) ) )
Starting December 3, join live sessions with database experts and the Fabric product team to learn just how easy it is to get started.
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Early Bird pricing ends December 9th.
User | Count |
---|---|
94 | |
86 | |
82 | |
70 | |
49 |
User | Count |
---|---|
143 | |
122 | |
109 | |
60 | |
55 |