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
AA622
Helper II
Helper II

Measure to subtract values within the same column using FILTER

So we are creating a dashboard for our sales reps to see whether on not they hit their target per month. There are tiers to our sales rep so naturally Salesrep1 won't have to generate as much as a Salesrep2 who is on another tier but they're aggregated IF they're in the same region

 

SalesRep2 will hit his target as long as his 3-4 Salesrep1's hit their targets. SalesRep2 also depends on 3rd party reps to make up the rest of his target.

SalesRep2 total target = SalesRep1 total sales (3-4 reps) + 3rd party rep sales

600k = 345k + 255k

 

The issue is that we have the SalesRep2 and SalesRep1 within the same table but also within the same column

Table[column] = target[salesrep]

 

I need to create a measure to get the salestotal of the 3rd party reps since we don't have access to all their data. How do i create a measure to subtract SalesRep1 from SalesRep2 within the same column and table? If i can do that I can get the sales data of the 3rd party reps

 

I already created a measure to sum the target sales for each rep

TotalTarget = SUM(Targettable[target])

Do i use FILTER to subtract the 2 values. Stuck here...

 

I also created another measure to calculate the MTDsales

TotalSalespermonth = SUMX(Targettable,targettable[salespermonth])

 

Let me know how best to do this please

 

thanks

 

 

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

Hi @AA622 ,

According to your description, I create a sample.

vkalyjmsft_0-1656319048210.png

In my understanding, you want to calculate the 3rd party rep sales under the rule "SalesRep2 total target = SalesRep1 total sales (3-4 reps) + 3rd party rep sales". Here, the SalesRep1 can be included in the calculation only when Sales greater or equal to Target. If this is the case, here's my solution.

Create a measure.

3rd party rep sales =
MAXX ( FILTER ( 'target', 'target'[Salesrep] = "SalesRep2" ), 'target'[Target] )
    - SUMX (
        FILTER (
            'target',
            'target'[Salesrep] = "SalesRep1"
                && 'target'[Sales] >= 'target'[Target]
        ),
        'target'[Sales]
    )

 Get the result.

vkalyjmsft_1-1656319357721.png

I attach my sample below for reference.

 

Best Regards,
Community Support Team _ kalyj

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

1 REPLY 1
v-yanjiang-msft
Community Support
Community Support

Hi @AA622 ,

According to your description, I create a sample.

vkalyjmsft_0-1656319048210.png

In my understanding, you want to calculate the 3rd party rep sales under the rule "SalesRep2 total target = SalesRep1 total sales (3-4 reps) + 3rd party rep sales". Here, the SalesRep1 can be included in the calculation only when Sales greater or equal to Target. If this is the case, here's my solution.

Create a measure.

3rd party rep sales =
MAXX ( FILTER ( 'target', 'target'[Salesrep] = "SalesRep2" ), 'target'[Target] )
    - SUMX (
        FILTER (
            'target',
            'target'[Salesrep] = "SalesRep1"
                && 'target'[Sales] >= 'target'[Target]
        ),
        'target'[Sales]
    )

 Get the result.

vkalyjmsft_1-1656319357721.png

I attach my sample below for reference.

 

Best Regards,
Community Support Team _ kalyj

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

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.