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

Calling all Data Engineers! Fabric Data Engineer (Exam DP-700) live sessions are back! Starting October 16th. Sign up.

Reply
Ilija89
New Contributor II

Calculating Weighted Sales

I need help in calculating weighted sales.

Context:

There are two tables; Sales transaction and Sales Weights tables (examples attached with dummy data).

Sales is divided into direct and indirect sales. If it is indirect sales is alocated to sales rep. who is covering that specific customer. On the other side if sales is direct, then sales amount should be splitted to sales reps by weights given in Sales Weights table.

Relationship between tables:

In order to create relationship between two tables, bridge table is created with unique code created by merging category and customer code.

  

How to create formula that will calculate weighted sales for direct sales for each sales rep per customer per category? Some switch formula 

Thanks

 

Bridge table

Bridge Table.png

Ilija89_0-1757324005721.png

Sales table

Sales Table.png

Weights table

Weights Table.png

 

1 ACCEPTED SOLUTION
v-dineshya
Honored Contributor II

Hi @Ilija89 ,

Thank you for the response, I have tried the solution based on your logic, but it is not giving exact result. you need to change your data and data model.

 

Please refer below two solutions.

 

1.  Direct Sales Allocated :=
SUMX(
FILTER( Sales, Sales[Sales Type] = "Direct" ),
VAR CatCust = Sales[Category-Customer Code]
VAR Amount = Sales[Sales amount]
VAR CurrentRep = SELECTEDVALUE( Weights[Sales Representative] )
VAR WeightVal =
CALCULATE(
MAX( Weights[Weight] ),
FILTER(
Weights,
Weights[Category-Customer Code] = CatCust
&& Weights[Sales Representative] = CurrentRep
)
)
RETURN Amount * COALESCE( WeightVal, 0 )
)

 

 

Indirect Sales Allocated :=
SUMX(
FILTER( Sales, Sales[Sales Type] = "Indirect" ),
IF( Sales[Sales Rep] = SELECTEDVALUE( Weights[Sales Representative] ),
Sales[Sales amount],
0
)
)

 

please refer output snap and PBIX file.

 

vdineshya_0-1760119617389.png

 

2.   

Direct Sales Allocated =
VAR CurrentRep = SELECTEDVALUE ( Weights[Sales Representative] )
RETURN
SUMX (
    VALUES ( Weights[Category-Customer Code] ),
    VAR CatCust = SELECTEDVALUE ( Weights[Category-Customer Code] )
    VAR CustCode = SELECTEDVALUE ( Weights[Customer code] )
    VAR Cat = SELECTEDVALUE ( Weights[Category] )
    VAR TotalDirectForCust =
        CALCULATE (
            SUM ( Sales[Sales amount] ),
            Sales[Sales Type] = "Direct",
            Sales[Customer code] = CustCode
        )
    VAR WeightVal =
        CALCULATE (
            MAX ( Weights[Weight] ),
            Weights[Category-Customer Code] = CatCust,
            Weights[Sales Representative] = CurrentRep
        )
    RETURN
        TotalDirectForCust * COALESCE ( WeightVal, 0 )
)
 
Indirect Sales Allocated =
VAR CurrentRep = SELECTEDVALUE ( Weights[Sales Representative] )
RETURN
CALCULATE (
    SUM ( Sales[Sales amount] ),
    Sales[Sales Type] = "Indirect",
    Sales[Sales Rep] = CurrentRep
)
 
vdineshya_1-1760119973728.png

 

 

I hope this information helps. Please do let us know if you have any further queries.

 

Regards,

Dinesh

 

View solution in original post

29 REPLIES 29
FBergamaschi
Contributor III

Hi @Ilija89,

it seems nothing difficult but to help you in the best possible way, please can you attach the tables with dummy data in a usable format? Not an image but text

 

Thanks

 

If this helped, please consider giving kudos and mark as a solution

@me in replies or I'll lose your thread

Want to check your DAX skills? Answer my biweekly DAX challenges on the kubisco Linkedin page

Consider voting this Power BI idea

Francesco Bergamaschi

MBA, M.Eng, M.Econ, Professor of BI

Ilija89
New Contributor II

Weights

CustomerCategoryCustomer codeSales RepresentativeWeightCategory-Customer Code
AB11abA.K25%1_1ab
AB21abB.J100%2_1ab
AB11abG.L75%1_1ab
AC11acA.K33%1_1ac
AC11acB.J33%1_1ac
AC11acG.L33%1_1ac
AF21afA.K50%2_1af
AF21afB.J50%2_1af
AF11afG.L100%1_1af
KG11kgA.K50%1_1kg
KG21kgB.J100%2_1kg
KG11kgG.L50%1_1kg

 

Sales table

CustomerSales TypeCategoryDateCustomer codeSales amountSales RepCategory-Customer Code
ABDirect1Jan-251ab             423,423Direct1_1ab
ABIndirect1Feb-251ab               43,342G.L1_1ab
ACDirect2Jan-251ac         4,444,556Direct2_1ac
AFDirect1Feb-251af               44,656Direct1_1af
KGIndirect2Feb-251kg                 7,878A.K2_1kg

 

Bridge table

CustomerCategoryCustomer codeCategory-Customer Code
AB11ab1_1ab
AB21ab2_1ab
AC11ac1_1ac
AC21ac2_1ac
AF11af1_1af
AF21af2_1af
KG11kg1_1kg
KG21kg2_1kg

 

Hi @FBergamaschi above are dummy data examples.

Thanks!

 

Hi @Ilija89 ,

 

Please add an example of what you need as output? a table including customers, sales rep, and weights?!

Hi @Selva-Salimi I need output as total sales of particular sales rep (sum of direct and indirect sales).per category per customer.

Thanks, Ilija

FBergamaschi
Contributor III

Hi @Ilija89 

I am almost there but it seems to me that the tables are not complete (?)


For example, in Sales there is a row for Cust KG, category 2 and Salesman AK which is not refelected in the weights table, am I wrong? If you can cover all the Sales cases in the weights table, that will help me debug and send you the solution

 

Thanks

 

If this helped, please consider giving kudos and mark as a solution

@me in replies or I'll lose your thread

Want to check your DAX skills? Answer my biweekly DAX challenges on the kubisco Linkedin page

Consider voting this Power BI idea

Francesco Bergamaschi

MBA, M.Eng, M.Econ, Professor of BI

Hi @FBergamaschi this is the case that I am facing with. In tis particualr situation if for specific customer sales rep is asigned then sales is equal to that sales rep, in other case when sales is direct then  we should calculate that row by multypling that sales with weights given for that customer.

v-dineshya
Honored Contributor II

Hi @Ilija89 ,

Thank you for reaching out to the Microsoft Community Forum.

 

You are expecting  formula that will calculate weighted sales for direct sales for each sales rep per customer per category.

 

Please refer below output snap and attached PBIX file.

 

vdineshya_0-1757417782345.png

 

vdineshya_1-1757417827041.png

 

I hope this information helps. Please do let us know if you have any further queries.

 

Regards,

Dinesh

 

v-dineshya
Honored Contributor II

Hi @Ilija89 ,

We haven’t heard from you on the last response and was just checking back to see if you have a resolution yet. And, if you have any further query do let us know.

 

Regards,

Dinesh

v-dineshya
Honored Contributor II

Hi @Ilija89 ,

We haven’t heard from you on the last response and was just checking back to see if you have a resolution yet. And, if you have any further query do let us know.

 

Regards,

Dinesh

Ilija89
New Contributor II

Hi @v-dineshya ,

 

Sorry for late reply. Thank you for solution, but I have one remark. In pbix file all sales reps have the same indirect sales but it shouldnt be. Formula is summing indirect sales and it is the same for all sales reps. G.L. should have 43,342 and A.K. 7,878 indirect sales while other sales reps should have 0. 

Hi @Ilija89 

 

Thanks to @v-dineshya , I think you need to update the measure as follows:

 

Weighted Sales =
SUMX (
    Sales,
    SWITCH (
        TRUE(),
        Sales[Sales Type] = "Indirect",
            CALCULATE(sum(Sales[Sales amount]),FILTER(Sales,Sales[Sales Rep]=SELECTEDVALUE(Weights[Sales Representative]))),
        Sales[Sales Type] = "Direct",
            Sales[Sales amount] *
            CALCULATE (
                MAX ( Weights[Weight] ),
                TREATAS ( { Sales[Category-Customer Code] }, Weights[Category-Customer Code] ),
                TREATAS ( VALUES ( Weights[Sales Representative] ), Weights[Sales Representative] )
            )
    )
)
 
 
If this post helps, then I would appreciate a thumbs up and mark it as the solution to help the other members find it more quickly.

Thanks @Selva-Salimi! I tried it, but it asigns indirect values for all customers for slaes reps that we have indirect sales. Do you know what we should change in calculation? 

@Ilija89 ,

 

Are you sure that you use "SELECTEDVALUE"?? would you please share your measure? and also would you please tell me about the relations between the tables? are they "single" direction?

hI @Selva-Salimi , latest measure attached:

Weighted Sales =
SUMX (
    Sales,
    SWITCH (
        TRUE(),
     
        Sales[Sales Type] = "Indirect" &&
        SELECTEDVALUE ( Weights[Sales Representative] ) = Sales[Sales Rep],
            Sales[Sales amount],

        Sales[Sales Type] = "Direct",
            Sales[Sales amount] *
            CALCULATE (
                MAX ( Weights[Weight] ),
                TREATAS ( { Sales[Category-Customer Code] }, Weights[Category-Customer Code] ),
                TREATAS ( VALUES ( Weights[Sales Representative] ), Weights[Sales Representative] )
            ),
        0
    )
)
Relations are "single" direction.

@Ilija89 ,

 

would you please update the "indirect" part, the same as what I have mentioned in previous post? I mean...

Sales[Sales Type] = "Indirect",
            CALCULATE(sum(Sales[Sales amount]),FILTER(Sales,Sales[Sales Rep]=SELECTEDVALUE(Weights[Sales Representative]))),
 
 

Hi @Selva-Salimi ,

thanks for assistance, below is expected output. Even if I changed formula based on your input it gives me different output than expacted. 

  Direct  Indirect  Total  
A.K   1,587,374           7,878   1,595,252
AB      105,856                  -        105,856
1      105,856       105,856
AC   1,481,519                  -     1,481,519
1   1,481,519    1,481,519
KG                  -             7,878           7,878
2            7,878           7,878
B.J   1,481,519                  -     1,481,519
AC   1,481,519                  -     1,481,519
1   1,481,519    1,481,519
G.L   1,843,742         43,342   1,887,084
AB      317,567         43,342      360,909
1      317,567         43,342      360,909
AC   1,481,519                  -     1,481,519
1   1,481,519    1,481,519
AF         44,656                  -           44,656
1         44,656          44,656
Ilija89
New Contributor II

Weight table

CustomerCategoryCustomer codeSales RepresentativeWeightCategory-Customer Code
AB11abA.K25%1_1ab
AB21abB.J100%2_1ab
AB11abG.L75%1_1ab
AC11acA.K33%1_1ac
AC11acB.J33%1_1ac
AC11acG.L33%1_1ac
AF21afA.K50%2_1af
AF21afB.J50%2_1af
AF11afG.L100%1_1af
KG11kgA.K50%1_1kg
KG21kgB.J100%2_1kg
KG11kgG.L50%1_1kg

Sales table

 

CustomerSales TypeCategoryDateCustomer codeSales amountSales RepCategory-Customer Code
ABDirect1Jan-251ab             423,423Direct1_1ab
ABIndirect1Feb-251ab               43,342G.L1_1ab
ACDirect1Jan-251ac         4,444,556Direct1_1ac
AFDirect1Feb-251af               44,656Direct1_1af
KGIndirect2Feb-251kg                 7,878A.K2_1kg

Bridge Table

CustomerCategoryCustomer codeCategory-Customer Code
AB11ab1_1ab
AB21ab2_1ab
AC11ac1_1ac
AC21ac2_1ac
AF11af1_1af
AF21af2_1af
KG11kg1_1kg
KG21kg2_1kg
 
v-dineshya
Honored Contributor II

Hi @Ilija89 ,

Please refer below updated DAX measure.

Weighted Sales =
SUMX (
    Sales,
    SWITCH (
        TRUE(),
     
        Sales[Sales Type] = "Indirect" &&
        SELECTEDVALUE ( Weights[Sales Representative] ) = Sales[Sales Rep],
            Sales[Sales amount],

        Sales[Sales Type] = "Direct",
            Sales[Sales amount] *
            CALCULATE (
                MAX ( Weights[Weight] ),
                TREATAS ( { Sales[Category-Customer Code] }, Weights[Category-Customer Code] ),
                TREATAS ( VALUES ( Weights[Sales Representative] ), Weights[Sales Representative] )
            ),
        0
    )
)
 
Please refer output snap and attached PBIX file.
 
vdineshya_0-1758019695611.png

 

I hope this information helps. Please do let us know if you have any further queries.

 

Regards,

Dinesh

Ilija89
New Contributor II

Hi @v-dineshya. thanks for replying, solution is partly correct. New formula assigns indirect value for sales reps but for all customers. For this particular case, indirect sales is available only for AB customer, category 1, for sales rep G.I. 43.342 and KG customer for sales rep A.K. 7.878 for category 2. For al lother customers we should have values, but this formula asign these values for all customers. Coul you check? thank you a lot for help!

v-bmanikante
Valued Contributor II

Hi @Ilija89,

 

I am also part of the CST team. Could you please share the expected output from the sample data you provided? This will help us investigate further and work on the measure effectively.

Apologies that the issue still persists, and thank you for your patience.

 

Regards,

B Manikanteswara Reddy

 

Hi @v-bmanikante  ,

thanks for assistance, below is expected output. 

  Direct  Indirect  Total  
A.K   1,587,374           7,878   1,595,252
AB      105,856                  -        105,856
1      105,856       105,856
AC   1,481,519                  -     1,481,519
1   1,481,519    1,481,519
KG                  -             7,878           7,878
2            7,878           7,878
B.J   1,481,519                  -     1,481,519
AC   1,481,519                  -     1,481,519
1   1,481,519    1,481,519
G.L   1,843,742         43,342   1,887,084
AB      317,567         43,342      360,909
1      317,567         43,342      360,909
AC   1,481,519                  -     1,481,519
1   1,481,519    1,481,519
AF         44,656                  -           44,656
1         44,656          44,656
Ilija89
New Contributor II

Weight table

CustomerCategoryCustomer codeSales RepresentativeWeightCategory-Customer Code
AB11abA.K25%1_1ab
AB21abB.J100%2_1ab
AB11abG.L75%1_1ab
AC11acA.K33%1_1ac
AC11acB.J33%1_1ac
AC11acG.L33%1_1ac
AF21afA.K50%2_1af
AF21afB.J50%2_1af
AF11afG.L100%1_1af
KG11kgA.K50%1_1kg
KG21kgB.J100%2_1kg
KG11kgG.L50%1_1kg

Sales table

 

CustomerSales TypeCategoryDateCustomer codeSales amountSales RepCategory-Customer Code
ABDirect1Jan-251ab             423,423Direct1_1ab
ABIndirect1Feb-251ab               43,342G.L1_1ab
ACDirect1Jan-251ac         4,444,556Direct1_1ac
AFDirect1Feb-251af               44,656Direct1_1af
KGIndirect2Feb-251kg                 7,878A.K2_1kg

Bridge Table

CustomerCategoryCustomer codeCategory-Customer Code
AB11ab1_1ab
AB21ab2_1ab
AC11ac1_1ac
AC21ac2_1ac
AF11af1_1af
AF21af2_1af
KG11kg1_1kg
KG21kg2_1kg
 
v-dineshya
Honored Contributor II

Hi @Ilija89 ,

Could you please share the expected output from the sample data you provided? This will help us investigate further and work on the measure effectively. Apologies that the issue still persists, and thank you for your patience.

 

Regards,

Dinesh

 

Ilija89
New Contributor II

Hi @v-dineshya ,

thanks for assistance, below is expected output. 

  Direct  Indirect  Total  
A.K   1,587,374           7,878   1,595,252
AB      105,856                  -        105,856
1      105,856       105,856
AC   1,481,519                  -     1,481,519
1   1,481,519    1,481,519
KG                  -             7,878           7,878
2            7,878           7,878
B.J   1,481,519                  -     1,481,519
AC   1,481,519                  -     1,481,519
1   1,481,519    1,481,519
G.L   1,843,742         43,342   1,887,084
AB      317,567         43,342      360,909
1      317,567         43,342      360,909
AC   1,481,519                  -     1,481,519
1   1,481,519    1,481,519
AF         44,656                  -           44,656
1         44,656          44,656
Ilija89
New Contributor II

Weight table

CustomerCategoryCustomer codeSales RepresentativeWeightCategory-Customer Code
AB11abA.K25%1_1ab
AB21abB.J100%2_1ab
AB11abG.L75%1_1ab
AC11acA.K33%1_1ac
AC11acB.J33%1_1ac
AC11acG.L33%1_1ac
AF21afA.K50%2_1af
AF21afB.J50%2_1af
AF11afG.L100%1_1af
KG11kgA.K50%1_1kg
KG21kgB.J100%2_1kg
KG11kgG.L50%1_1kg

Sales table

 

CustomerSales TypeCategoryDateCustomer codeSales amountSales RepCategory-Customer Code
ABDirect1Jan-251ab             423,423Direct1_1ab
ABIndirect1Feb-251ab               43,342G.L1_1ab
ACDirect1Jan-251ac         4,444,556Direct1_1ac
AFDirect1Feb-251af               44,656Direct1_1af
KGIndirect2Feb-251kg                 7,878A.K2_1kg

Bridge Table

CustomerCategoryCustomer codeCategory-Customer Code
AB11ab1_1ab
AB21ab2_1ab
AC11ac1_1ac
AC21ac2_1ac
AF11af1_1af
AF21af2_1af
KG11kg1_1kg
KG21kg2_1kg
v-dineshya
Honored Contributor II

Hi @Ilija89 ,

Thanks for the update, Could you please elaborate the logic behind the expected output or Please explain your query in detail. I have tried all the options, but i am not getting the expected output.

 

Regards,

Dinesh

v-dineshya
Honored Contributor II

Hi @Ilija89 ,

We haven’t heard from you on the last response and was just checking back to see if you have a resolution yet. And, if you have any further query do let us know.

 

Regards,

Dinesh

 

Ilija89
New Contributor II

Hi @v-dineshya ,

Logic is explained below:

 

  Direct  Indirect  Total   Logic 
A.K   1,587,374           7,878   1,595,252 
AB      105,856                  -        105,856 
1      105,856       105,856Direct sales from customer AB, we are multypling direct sales of AB with weight - 25% out of 423.423
AC   1,481,519                  -     1,481,519 
1   1,481,519    1,481,519Direct sales from customer AC, we are multypling direct sales of A.C with weight - 33% out of 4.444.556
KG                  -             7,878           7,878 
2            7,878           7,878This is indirec tsales from A.K. so it is 7.878 it is wo using weights
B.J   1,481,519                  -     1,481,519 
AC   1,481,519                  -     1,481,519 
1   1,481,519    1,481,519Direct sales from customer AC, we are multypling direct sales of A.C with weight - 33% out of 4.444.556
G.L   1,843,742         43,342   1,887,084 
AB      317,567         43,342      360,909 
1      317,567         43,342      360,909Direct sales from customer AB, we are multypling direct sales of AB with weight - 75% out of 423.423 while indirect sales corresponds to indirect sales of G.L which is 43.342
AC   1,481,519                  -     1,481,519 
1   1,481,519    1,481,519Direct sales from customer AC, we are multypling direct sales of A.C with weight - 33% out of 4.444.556
AF         44,656                  -           44,656 
1         44,656          44,656Direct sales from customer AF, we are multypling direct sales of AF with weight - 100%(1) out of 44.656
v-dineshya
Honored Contributor II

Hi @Ilija89 ,

Thank you for the response, I have tried the solution based on your logic, but it is not giving exact result. you need to change your data and data model.

 

Please refer below two solutions.

 

1.  Direct Sales Allocated :=
SUMX(
FILTER( Sales, Sales[Sales Type] = "Direct" ),
VAR CatCust = Sales[Category-Customer Code]
VAR Amount = Sales[Sales amount]
VAR CurrentRep = SELECTEDVALUE( Weights[Sales Representative] )
VAR WeightVal =
CALCULATE(
MAX( Weights[Weight] ),
FILTER(
Weights,
Weights[Category-Customer Code] = CatCust
&& Weights[Sales Representative] = CurrentRep
)
)
RETURN Amount * COALESCE( WeightVal, 0 )
)

 

 

Indirect Sales Allocated :=
SUMX(
FILTER( Sales, Sales[Sales Type] = "Indirect" ),
IF( Sales[Sales Rep] = SELECTEDVALUE( Weights[Sales Representative] ),
Sales[Sales amount],
0
)
)

 

please refer output snap and PBIX file.

 

vdineshya_0-1760119617389.png

 

2.   

Direct Sales Allocated =
VAR CurrentRep = SELECTEDVALUE ( Weights[Sales Representative] )
RETURN
SUMX (
    VALUES ( Weights[Category-Customer Code] ),
    VAR CatCust = SELECTEDVALUE ( Weights[Category-Customer Code] )
    VAR CustCode = SELECTEDVALUE ( Weights[Customer code] )
    VAR Cat = SELECTEDVALUE ( Weights[Category] )
    VAR TotalDirectForCust =
        CALCULATE (
            SUM ( Sales[Sales amount] ),
            Sales[Sales Type] = "Direct",
            Sales[Customer code] = CustCode
        )
    VAR WeightVal =
        CALCULATE (
            MAX ( Weights[Weight] ),
            Weights[Category-Customer Code] = CatCust,
            Weights[Sales Representative] = CurrentRep
        )
    RETURN
        TotalDirectForCust * COALESCE ( WeightVal, 0 )
)
 
Indirect Sales Allocated =
VAR CurrentRep = SELECTEDVALUE ( Weights[Sales Representative] )
RETURN
CALCULATE (
    SUM ( Sales[Sales amount] ),
    Sales[Sales Type] = "Indirect",
    Sales[Sales Rep] = CurrentRep
)
 
vdineshya_1-1760119973728.png

 

 

I hope this information helps. Please do let us know if you have any further queries.

 

Regards,

Dinesh

 

Helpful resources

Announcements
Users online (25)