cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
Post Patron
Post Patron

Outstanding Invoice total as of Selected Date

Dear All 

 

I need your help to create few measure  as below. Can you please help?

 

I have attached the data for your reference. Thank You for your help in advance.

 

1) If Invoice date & cash receipt date is less than or equal to selected date

AND

Invoice Amount if fully Paid

 

Result

Paid Invoices

 

2) If Invoice is not paid or partially paid as of selected date

 

Result

Sum of Total Outstanding Invoices as of selected date (*For partially paid Invoices only balance should be calculated as of selected date)

 

3) Total Invoice Amount On or Before as of Selected Date

 

4) Total Invoice Amount After as of Selected Date

 

5) Unpaid Invoices as of Selected Date (Outstanding)

 

Download PBIX

1 ACCEPTED SOLUTION

Accepted Solutions

Hi @gauravnarchal ,

 

Please refer to the measure below:

 

 

Paid Invoices or Outstanding Invoices 2 =
VAR SelectedDate =
    MAX ( 'Calendar'[Date] )
VAR ReceiptDate =
    CALCULATE (
        MAX ( Cash_receipt[Receipt_Date] ),
        FILTER (
            Cash_receipt,
            Cash_receipt[invoice_id] = MAX ( ARInvoices[invoice_id] )
        )
    )
RETURN
    IF (
        HASONEVALUE ( ARInvoices[invoice_id] ),
        IF (
            MAX ( ARInvoices[invoice_date] ) <= SelectedDate
                && ReceiptDate <= SelectedDate
                && NOT ( ISBLANK ( ReceiptDate ) ),
            BLANK (),
            CALCULATE (
                SUM ( ARInvoices[InvoiceAmount] ),
                FILTER (
                    ARInvoices,
                    ARInvoices[invoice_date] <= SelectedDate
                        && ARInvoices[invoice_id] IN DISTINCT ( ARInvoices[invoice_id] )
                )
            )
                - CALCULATE (
                    SUM ( Cash_receipt[ReceiptAmount] ),
                    FILTER (
                        Cash_receipt,
                        Cash_receipt[Receipt_Date] <= SelectedDate
                            && Cash_receipt[invoice_id] IN DISTINCT ( ARInvoices[invoice_id] )
                    )
                )
        ),
        [Unpaid Invoices as of Selected Date (Outstanding)]
    )

 

 

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

 

Best Regards,

Dedmon Dai

View solution in original post

6 REPLIES 6
Microsoft
Microsoft

Hello @gauravnarchal ,

Please refer to the following measurement for your for 1) and 2):

Paid Invoices or Outstanding Invoices =
VAR SelectedDate =
    MAX ( 'Calendar'[Date] )
VAR ReceiptDate =
    CALCULATE (
        MAX ( Cash_receipt[Receipt_Date] ),
        FILTER (
            Cash_receipt,
            Cash_receipt[invoice_id] = MAX ( ARInvoices[invoice_id] )
        )
    )
RETURN
    IF (
        MAX ( ARInvoices[invoice_date] ) <= SelectedDate
            && ReceiptDate <= SelectedDate
            && NOT ( ISBLANK ( ReceiptDate ) ),
        "Paid Invoices",
        CALCULATE (
            SUM ( ARInvoices[InvoiceAmount] ),
            FILTER (
                ARInvoices,
                ARInvoices[invoice_date] <= SelectedDate
                    && ARInvoices[invoice_id] IN DISTINCT ( ARInvoices[invoice_id] )
            )
        )
            - CALCULATE (
                SUM ( Cash_receipt[ReceiptAmount] ),
                FILTER (
                    Cash_receipt,
                    Cash_receipt[Receipt_Date] <= SelectedDate
                        && Cash_receipt[invoice_id] IN DISTINCT ( ARInvoices[invoice_id] )
                )
            )
    )

And the following measures for 3,4)y5):

Total Invoice Amount On or Before as of Selected Date = VAR SelectedDate = MAX('Calendar'[Date]) Return CALCULATE(SUM(ARInvoices[InvoiceAmount]),FILTER(ALL(ARInvoices),ARInvoices[invoice_date]<=SelectedDate))

Total Invoice Amount After as of Selected Date = VAR SelectedDate = MAX('Calendar'[Date]) Return CALCULATE(SUM(ARInvoices[InvoiceAmount]),FILTER(ALL(ARInvoices),ARInvoices[invoice_date]>=SelectedDate))

Unpaid Invoices as of Selected Date (Outstanding) = VAR SelectedDate = MAX('Calendar'[Date]) return CALCULATE(SUM(ARInvoices[InvoiceAmount]),FILTER(ARInvoices,ARInvoices[invoice_date]<= SelectedDate&&ARInvoices[invoice_id] IN DISTINCT(ARInvoices[invoice_id])))-CALCULATE(SUM(Cash_receipt[ReceiptAmount]),FILTER(Cash_receipt,Cash_receipt[Receipt_Date]<=SelectedDate&&Cash_receipt[invoice_id] IN DISTINCT(ARInvoices[invoice_id])))

Capture.PNG

For more information, see the pbix: https://qiuyunus-my.sharepoint.com/:u:/g/personal/pbipro_qiuyunus_onmicrosoft_com/EcdVIyl6dB9HgV98-G...

If this post helps, then consider Accept it as the solution to help other members find it faster.

Best regards

Dedmon Dai

@v-deddai1-msft - Brilliant..

 

Thank you for your help!

@v-deddai1-msft 

How can I filter/remove Paid Invoices from the "Paid Invoices or Outstanding Invoices measure"? The table should only show outstanding Invoices.

 

Thank you for all your help.

 

gauravnarchal_0-1599159934113.png

 

Hi @gauravnarchal ,

 

Just change the measure to show blank:

 

 

Paid Invoices or Outstanding Invoices =
VAR SelectedDate =
    MAX ( 'Calendar'[Date] )
VAR ReceiptDate =
    CALCULATE (
        MAX ( Cash_receipt[Receipt_Date] ),
        FILTER (
            Cash_receipt,
            Cash_receipt[invoice_id] = MAX ( ARInvoices[invoice_id] )
        )
    )
RETURN
    IF (
        MAX ( ARInvoices[invoice_date] ) <= SelectedDate
            && ReceiptDate <= SelectedDate
            && NOT ( ISBLANK ( ReceiptDate ) ),
        Blank(),
        CALCULATE (
            SUM ( ARInvoices[InvoiceAmount] ),
            FILTER (
                ARInvoices,
                ARInvoices[invoice_date] <= SelectedDate
                    && ARInvoices[invoice_id] IN DISTINCT ( ARInvoices[invoice_id] )
            )
        )
            - CALCULATE (
                SUM ( Cash_receipt[ReceiptAmount] ),
                FILTER (
                    Cash_receipt,
                    Cash_receipt[Receipt_Date] <= SelectedDate
                        && Cash_receipt[invoice_id] IN DISTINCT ( ARInvoices[invoice_id] )
                )
            )
    )

 

 

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

 

Best Regards,

Dedmon Dai

Hello @v-deddai1-msft 

 

I have changed the measure as advised. Now i don't see the total when I select any the date after 12th June.

 

I have attached the PBIX.

 

Thank you for the help in advance.

 

Gaurav

 

Download PBIX

Hi @gauravnarchal ,

 

Please refer to the measure below:

 

 

Paid Invoices or Outstanding Invoices 2 =
VAR SelectedDate =
    MAX ( 'Calendar'[Date] )
VAR ReceiptDate =
    CALCULATE (
        MAX ( Cash_receipt[Receipt_Date] ),
        FILTER (
            Cash_receipt,
            Cash_receipt[invoice_id] = MAX ( ARInvoices[invoice_id] )
        )
    )
RETURN
    IF (
        HASONEVALUE ( ARInvoices[invoice_id] ),
        IF (
            MAX ( ARInvoices[invoice_date] ) <= SelectedDate
                && ReceiptDate <= SelectedDate
                && NOT ( ISBLANK ( ReceiptDate ) ),
            BLANK (),
            CALCULATE (
                SUM ( ARInvoices[InvoiceAmount] ),
                FILTER (
                    ARInvoices,
                    ARInvoices[invoice_date] <= SelectedDate
                        && ARInvoices[invoice_id] IN DISTINCT ( ARInvoices[invoice_id] )
                )
            )
                - CALCULATE (
                    SUM ( Cash_receipt[ReceiptAmount] ),
                    FILTER (
                        Cash_receipt,
                        Cash_receipt[Receipt_Date] <= SelectedDate
                            && Cash_receipt[invoice_id] IN DISTINCT ( ARInvoices[invoice_id] )
                    )
                )
        ),
        [Unpaid Invoices as of Selected Date (Outstanding)]
    )

 

 

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

 

Best Regards,

Dedmon Dai

View solution in original post

Helpful resources

Announcements
November Update

Check it Out!

Click here to read more about the November 2020 Updates!

Community Conference

Power Platform Community Conference

Check out the on demand sessions that are available now!

secondImage

Power Platform October Community Highlights

Check out the top community contributors across all of the communities

secondImage

Create an end-to-end data and analytics solution

Learn how Power BI works with the latest Azure data and analytics innovations at the digital event with Microsoft CEO Satya Nadella.

Top Solution Authors
Top Kudoed Authors