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

Earn the coveted Fabric Analytics Engineer certification. 100% off your exam for a limited time only!

Reply
elkjoperik
Helper II
Helper II

IF filter value does not exist, then use other values

Hi!

I have a problem I have not found any solutions to. 

 

I've made a dynamic this week vs last week metric;

 

Sales PW =

VAR CurrentWeek = SELECTEDVALUE(Date[Week Nr])
VAR CurrentYear = SELECTEDVALUE(Date[Year])
VAR MaxWeekNumber = CALCULATE(MAX(Date[Week Nr]);ALL(Date))


// If week = 1, then it will calculate against week 52 or 53 fix
RETURN
SUMX(
FILTER(ALL(Date);
IF(CurrentWeek = 1;
Date[Week Nr] = MaxWeekNumber && Date[Year] = CurrentYear - 1;
Date[Week Nr] = CurrentWeek -1 && Date[Year] = CurrentYear) );
[Sum Revenue product])

 

The forumla works great, but, I have a segment for type of revenue:

- Campaign sales

- Email sales

- Non campaign sale 

 

and so on.

 

The problem

- If i select week 24, I have two segments; campaign sales and non campaign sale.  

- I select "campaign sale" to see all the product sales from this segment, and want to see this against last week.

 

Since I've used the segment "campaign sale" and i dint have this in week 23, it says i had no sales. 

 

How can i bypass this so it will calculate all sales from week 23 ? 

- I would like to see what sale I had in week 23 on the difff

1 ACCEPTED SOLUTION

Hi @elkjoperik,

 

There is a solution. Please refer to the file in the attachment. You need to rebuild the model. It's hard to filter the proper data in the model in which all the data is stored in one table. 

Solution =
VAR lastweekTotal =
    CALCULATE (
        SUM ( LW_DUMMY[Revenue FY] ),
        FILTER (
            ALL ( 'Calendar' ),
            'Calendar'[WeekNum]
                = MIN ( 'Calendar'[WeekNum] ) - 1
        )
    )
RETURN
    IF (
        ISBLANK ( lastweekTotal ),
        CALCULATE (
            SUM ( LW_DUMMY[Revenue FY] ),
            FILTER (
                ALL ( 'Calendar' ),
                'Calendar'[WeekNum]
                    = MIN ( 'Calendar'[WeekNum] ) - 1
            ),
            ALL ( Segments )
        ),
        lastweekTotal
    )

IF-filter-value-does-not-exist-then-use-other-values

Best Regards,
Dale

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

View solution in original post

11 REPLIES 11
v-jiascu-msft
Employee
Employee

Hi @elkjoperik,

 

Could you please mark the proper answers as solutions or share your solutions?

Best Regards,
Dale

Community Support Team _ Dale
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
v-jiascu-msft
Employee
Employee

Hi @elkjoperik,

 

It's possible. You need to create a new table TypeOfRevenue then establish a relationship with your current table. You can bypass the filter using "ALL". But the details depend on your data and its structure. Can you share a dummy sample, please?

 

Best Regards,

Dale

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

Thank you for your reply, sorry for my late reply. 

What I'm trying to do is:

 

IF I've selected Segment = email (for example), I would like to find the last week values, without searching for last weeks sales with FILTER = email. 

 

I want to find out this weeks sales through email (all the SKUs) and benchmark that against last week sales, 

 

If I havn't got any email sales last week, the current state of the PBI will return 0 in revenue, but, if I somehow make it search through all segments last week, I will get a result.

Did this clear things up ?

Hi @elkjoperik,

 

Can you share a dummy sample? Then I can write down the DAX formula.

 

 

Best Regards,
Dale

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

@v-jiascu-msft  found any solution? 

Hi Dale,

Thanks for your reply and time.

 

I've made a dummy setup (replaced data), but the setup is identical to my orginal setup

You can find it here

 

In this dummy sample, the "Sales PW" (sales past week) is not affected by the "Segment" filter. 

But what I want is when I select the filter "segment", I want it to select the current SKUs, but ignore the current segment when it comes to find the revenue last week from the segment. 

Hi @elkjoperik,

 

There is a solution. Please refer to the file in the attachment. You need to rebuild the model. It's hard to filter the proper data in the model in which all the data is stored in one table. 

Solution =
VAR lastweekTotal =
    CALCULATE (
        SUM ( LW_DUMMY[Revenue FY] ),
        FILTER (
            ALL ( 'Calendar' ),
            'Calendar'[WeekNum]
                = MIN ( 'Calendar'[WeekNum] ) - 1
        )
    )
RETURN
    IF (
        ISBLANK ( lastweekTotal ),
        CALCULATE (
            SUM ( LW_DUMMY[Revenue FY] ),
            FILTER (
                ALL ( 'Calendar' ),
                'Calendar'[WeekNum]
                    = MIN ( 'Calendar'[WeekNum] ) - 1
            ),
            ALL ( Segments )
        ),
        lastweekTotal
    )

IF-filter-value-does-not-exist-then-use-other-values

Best Regards,
Dale

Community Support Team _ Dale
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Anonymous
Not applicable

Getting an error trying to download your file.  Please update the link.

Hi @Anonymous,

 

I'm glad it helps. Please try this upgraded formula that will respond to the year slicer. You can download the file from https://1drv.ms/u/s!ArTqPk2pu-BkhBLE5poCyLQsDBnQ.

 

Solution 2 =
VAR lastweekTotal =
    CALCULATE (
        SUM ( LW_DUMMY[Revenue FY] ),
        FILTER (
            ALL ( 'Calendar'[WeekNum] ),
            'Calendar'[WeekNum]
                = MIN ( 'Calendar'[WeekNum] ) - 1
        )
    )
RETURN
    IF (
        ISBLANK ( lastweekTotal ),
        CALCULATE (
            SUM ( LW_DUMMY[Revenue FY] ),
            FILTER (
                ALL ( 'Calendar'[WeekNum] ),
                'Calendar'[WeekNum]
                    = MIN ( 'Calendar'[WeekNum] ) - 1
            ),
            ALL ( Segments )
        ),
        lastweekTotal
    )

 

Best Regards,
Dale

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

I also can't download the file you've attached

WOW! That worked epic!

 

Just one thing, I also have a YEAR filter, how would I integrate that into this formula ? Because now the formula gets the right week, but it takes sales from all years and not selected year

Helpful resources

Announcements
April AMA free

Microsoft Fabric AMA Livestream

Join us Tuesday, April 09, 9:00 – 10:00 AM PST for a live, expert-led Q&A session on all things Microsoft Fabric!

March Fabric Community Update

Fabric Community Update - March 2024

Find out what's new and trending in the Fabric Community.