Microsoft is giving away 50,000 FREE Microsoft Certification exam vouchers!
Enter the sweepstakes now!Prepping for a Fabric certification exam? Join us for a live prep session with exam experts to learn how to pass the exam. Register now.
Hi dear all,
I have a problem of how to calculate the Running Balance. I already have a table with the Allocation of each payment and the history of an Invoice.
In my table if i have an Invoice which is paid by 3 payments, i will have 3 lines for this invoice with the Allocated Amount (The amount of the payment which is allocated to this invoice) the Remaining Balance (Remaining Balance of this invoice after that Payment), The Payment Date, Invoice Date, The Customer, Invoice ID, The Initial Amount of the Invoice (for example if the remaining balance now is 1000 but the invoice was for 10000 in the begining i will have 10000 in the Total Amount).
If for an invoice i do not have any payment yes the Payment Date, Payment ID, will be blank and the Remaining Balance will contain the whole amount.
I have an example of my table below.
What i want is to create a measure or calculated column i don't care which will give me the Running Balance in a visual. So i will have a slicer with the date ( i am not sure which date i should use in the slicer, invoice date or payment date) and when i will filter it for example on a date i want to see the Balance on that Date.
Taking an example from my table below, if i want to see the Balance for Customer 1 ,on 2/3/2023 i should see
100000 (Iinvoice ID 100) + 15000 (Invoice ID 102) + 5000 (Invoice ID 103) + 100000 (Invoice ID 105) so the Open Balance at 2/3/2023 was 220000.
Allocation Table in the link below:
Solved! Go to Solution.
Hi @pbi1908 ,
Here are the steps you can follow:
1. Create calculated table.
Table 2 =
CALENDAR(
DATE(2023,2,1),
DATE(2023,12,31))
2. Create measure.
Flag =
var _select=SELECTEDVALUE('Table 2'[Date])
return
IF(
MAX('Table'[INVOICE_DATE])=MINX(FILTER(ALL('Table'),'Table'[CUSTOMER_ID]=MAX('Table'[CUSTOMER_ID])),[INVOICE_DATE])
&&
MAX('Table'[INVOICE_ID])=MINX(FILTER(ALL('Table'),'Table'[CUSTOMER_ID]=MAX('Table'[CUSTOMER_ID])),[INVOICE_ID])
,
MAX('Table'[REMAINING_BALANCE]),
IF(
MAX('Table'[PAYMENT_DATE])=BLANK()&&MAX('Table'[INVOICE_ID])<>MINX(FILTER(ALL('Table'),'Table'[CUSTOMER_ID]=MAX('Table'[CUSTOMER_ID])),[INVOICE_ID]),BLANK(),
IF(
MAX('Table'[PAYMENT_DATE])<=_select,MAX('Table'[REMAINING_BALANCE]),BLANK())
))
Sum_All =
SUMX(
ALL('Table'),[Flag])
3. Result:
[Invoice_id]=101 is also during slicer filtering, so it is also added
Best Regards,
Liu Yang
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly
Hi @pbi1908 ,
Here are the steps you can follow:
1. Create calculated table.
Table 2 =
CALENDAR(
DATE(2023,2,1),
DATE(2023,12,31))
2. Create measure.
Flag =
var _select=SELECTEDVALUE('Table 2'[Date])
return
IF(
MAX('Table'[INVOICE_DATE])=MINX(FILTER(ALL('Table'),'Table'[CUSTOMER_ID]=MAX('Table'[CUSTOMER_ID])),[INVOICE_DATE])
&&
MAX('Table'[INVOICE_ID])=MINX(FILTER(ALL('Table'),'Table'[CUSTOMER_ID]=MAX('Table'[CUSTOMER_ID])),[INVOICE_ID])
,
MAX('Table'[REMAINING_BALANCE]),
IF(
MAX('Table'[PAYMENT_DATE])=BLANK()&&MAX('Table'[INVOICE_ID])<>MINX(FILTER(ALL('Table'),'Table'[CUSTOMER_ID]=MAX('Table'[CUSTOMER_ID])),[INVOICE_ID]),BLANK(),
IF(
MAX('Table'[PAYMENT_DATE])<=_select,MAX('Table'[REMAINING_BALANCE]),BLANK())
))
Sum_All =
SUMX(
ALL('Table'),[Flag])
3. Result:
[Invoice_id]=101 is also during slicer filtering, so it is also added
Best Regards,
Liu Yang
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly
Check out the May 2025 Power BI update to learn about new features.
Explore and share Fabric Notebooks to boost Power BI insights in the new community notebooks gallery.
User | Count |
---|---|
72 | |
71 | |
70 | |
51 | |
47 |
User | Count |
---|---|
45 | |
38 | |
29 | |
29 | |
28 |