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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
NandoBI
Frequent Visitor

Relative date filter to invoice entries

Hi Community,

 

So i have a table:
Database$SalesInvoiceLine

Containing columns:
Database$SalesInvoiceLine'[Posting Date]
Database$SalesInvoiceLine'[Sell-to Customer No_]

 

I'm am trying to filter out Customers who havent placed an order (so haven't been invoiced) > 2 months.

 

But: The returned value can NOT show Customers who both: 

DID NOT place an order > 2 months 

DID place an order >2 months

 

Have been searching the community for ages. And have been trying different formulas... for ages.

 

Hope someone can help me out!

1 ACCEPTED SOLUTION
v-eachen-msft
Community Support
Community Support

Hi @NandoBI ,

 

Here is my sample data.

4-2.PNG

You need to create these new columns.

rank =
RANKX (
    FILTER (
        'Database$SalesInvoiceLine',
        'Database$SalesInvoiceLine'[Sell-to Customer No_]
            = EARLIER ( 'Database$SalesInvoiceLine'[Sell-to Customer No_] )
    ),
    'Database$SalesInvoiceLine'[Posting Date],
    ,
    ASC,
    DENSE
)
previous date =
CALCULATE (
    FIRSTNONBLANK ( 'Database$SalesInvoiceLine'[Posting Date], 1 ),
    FILTER (
        'Database$SalesInvoiceLine',
        'Database$SalesInvoiceLine'[Sell-to Customer No_]
            = EARLIER ( 'Database$SalesInvoiceLine'[Sell-to Customer No_] )
            && 'Database$SalesInvoiceLine'[rank]
                = EARLIER ( 'Database$SalesInvoiceLine'[rank] ) - 1
    )
)
result =
VAR a =
    CALCULATE (
        LASTDATE ( 'Database$SalesInvoiceLine'[Posting Date] ),
        ALLEXCEPT (
            'Database$SalesInvoiceLine',
            'Database$SalesInvoiceLine'[Sell-to Customer No_]
        )
    )
RETURN
    IF (
        DATEDIFF ( a, TODAY (), DAY ) > 60,
        TRUE,
        IF (
            'Database$SalesInvoiceLine'[previous date] <> BLANK ()
                && DATEDIFF (
                    'Database$SalesInvoiceLine'[previous date],
                    'Database$SalesInvoiceLine'[Posting Date],
                    DAY
                ) > 60,
            TRUE,
            FALSE
        )
    )

Then use filter to display your results.4-1.PNG

 

Best Regards,

Eads

 

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

Community Support Team _ Eads
If this post helps, then please consider Accept it as the solution to help the other members find it.

View solution in original post

1 REPLY 1
v-eachen-msft
Community Support
Community Support

Hi @NandoBI ,

 

Here is my sample data.

4-2.PNG

You need to create these new columns.

rank =
RANKX (
    FILTER (
        'Database$SalesInvoiceLine',
        'Database$SalesInvoiceLine'[Sell-to Customer No_]
            = EARLIER ( 'Database$SalesInvoiceLine'[Sell-to Customer No_] )
    ),
    'Database$SalesInvoiceLine'[Posting Date],
    ,
    ASC,
    DENSE
)
previous date =
CALCULATE (
    FIRSTNONBLANK ( 'Database$SalesInvoiceLine'[Posting Date], 1 ),
    FILTER (
        'Database$SalesInvoiceLine',
        'Database$SalesInvoiceLine'[Sell-to Customer No_]
            = EARLIER ( 'Database$SalesInvoiceLine'[Sell-to Customer No_] )
            && 'Database$SalesInvoiceLine'[rank]
                = EARLIER ( 'Database$SalesInvoiceLine'[rank] ) - 1
    )
)
result =
VAR a =
    CALCULATE (
        LASTDATE ( 'Database$SalesInvoiceLine'[Posting Date] ),
        ALLEXCEPT (
            'Database$SalesInvoiceLine',
            'Database$SalesInvoiceLine'[Sell-to Customer No_]
        )
    )
RETURN
    IF (
        DATEDIFF ( a, TODAY (), DAY ) > 60,
        TRUE,
        IF (
            'Database$SalesInvoiceLine'[previous date] <> BLANK ()
                && DATEDIFF (
                    'Database$SalesInvoiceLine'[previous date],
                    'Database$SalesInvoiceLine'[Posting Date],
                    DAY
                ) > 60,
            TRUE,
            FALSE
        )
    )

Then use filter to display your results.4-1.PNG

 

Best Regards,

Eads

 

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

Community Support Team _ Eads
If this post helps, then please consider Accept it as the solution to help the other members find it.

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

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.