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

Compete to become Power BI Data Viz World Champion! First round ends August 18th. Get started.

Reply
Brynieboy
Regular Visitor

Help with an error in formula

Hi,

 

I have a formula that works correctly in excel, however when I recreate this in Power Bi I get the following error message "The SUM function only accepts a column reference as the argument number 1."

 

The formula calculates commissions earned by sales staff based upon how many new cars and used cars are sold against their new and used targets.  Here is the criteria:

 

Either 100% of New target and at least 80% of used target OR

80% at least of new target and 100% of used target

If above is achieved then all sales are at £100 each otherwise they will be at £25 each

If both targets are hit 100% then any additional cars are at £150

 

Here is the excel formula

 

=IF(AND(SUM(B:B)>=SUM(I:I),SUM(C:C)>=SUM(K:K)),(SUM(B:B)*100+SUM(C:C)*100)+((SUM(B:B)+S UM(C:C)-SUM(I:I)- SUM(K:K))*50),IF(OR(AND(SUM(B:B)>=SUM(I:I),SUM(C:C)>=SUM(L:L)), AND(SUM(B:B)>=SUM(J:J),SUM(C:C)>=SUM(K:K))),SUM(B:B)*100+SUM(C:C)*100,SUM(B:B)*25+SUM(C:C)*25)) 

B = New Sold

C = Used Sold

I = New Target

J = New 80%

J = New 80&

K = Used Target

L = Used 80%

 

Here is my Power Bi Formula

Commission = IF(AND(SUM(Sheet1[New Sold])>=SUM(Sheet1[New Target]),SUM(Sheet1[Used Sold])>=SUM(Sheet1[Used Target])),(SUM([Total Sold])*100+SUM(Sheet1[Used Sold])*100)+((SUM(Sheet1[New Sold])+sum(Sheet1[Used Sold])-sum(Sheet1[New Target])-sum(Sheet1[Used Target]))*50),IF(OR(AND(SUM(Sheet1[New Target])>=SUM(Sheet1[New Target]),SUM(Sheet1[Used Sold])>=SUM(Sheet1[Used 80%])),AND(SUM(Sheet1[New Sold])>=SUM(Sheet1[New 80%]),SUM(Sheet1[Used Sold])>=sum(Sheet1[Used Target]))),SUM(Sheet1[New Sold])*100+SUM(Sheet1[Used Sold])*100,SUM(Sheet1[New Sold])*25+SUM(Sheet1[Used Sold])*25))

 

Please help, this is driving me crazy 🙂

 

Thanks in advance

 

 

1 ACCEPTED SOLUTION
Anonymous
Not applicable

Hi @Brynieboy 

Due to I dont know your data, I make a sample in excel just like yours.

1.png

I tried your dax in Excel and get the result as below:

2.png

I import the excel into the desktop and use calculated column.

 

Commission2 = 
VAR _NewSold = SUM(Sheet1[New Sold])
VAR _UsedSold = SUM(Sheet1[Used Sold])
VAR _NewTarget= SUM(Sheet1[New Target])
VAR _UsedTarget = SUM(Sheet1[Used Target])
VAR _NewT80 = SUM(Sheet1[New 80%])
VAR _UsedT80 = SUM(Sheet1[Used 80%])
VAR _AllSold= SUM(Sheet1[New Sold])+SUM(Sheet1[Used Sold])
VAR _AllTarget= SUM(Sheet1[New Target])+SUM(Sheet1[Used Target])
return
IF (
    AND (_NewSold >= _NewTarget ,_UsedSold >= _UsedTarget),
      _AllSold*150-_AllTarget*50 ,
    IF (
        OR (
            AND (_NewSold >=_NewTarget,_UsedSold >_UsedT80 ),
            AND (_NewSold >=_NewT80, _UsedSold>= _UsedTarget)
        ),
       _AllSold*100,
       _AllSold*25
    )
)

 

Result:

3.png

You can download the pbix file form this link:

https://qiuyunus-my.sharepoint.com/:u:/g/personal/tongzhou_qiuyunus_onmicrosoft_com/EWyRKsHutiRGgi1w...

 

Best Regards,

Rico Zhou

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

3 REPLIES 3
Anonymous
Not applicable

Hi @Brynieboy 

Could you tell me if your problem has been solved? If it is, kindly Accept it as the solution. More people will benefit from it. Or you are still confused about it, please provide me with more details about your table and your problem or share me with your pbix file from your onedrive business.

 

Best Regards,

Rico Zhou

Anonymous
Not applicable

Hi @Brynieboy 

Due to I dont know your data, I make a sample in excel just like yours.

1.png

I tried your dax in Excel and get the result as below:

2.png

I import the excel into the desktop and use calculated column.

 

Commission2 = 
VAR _NewSold = SUM(Sheet1[New Sold])
VAR _UsedSold = SUM(Sheet1[Used Sold])
VAR _NewTarget= SUM(Sheet1[New Target])
VAR _UsedTarget = SUM(Sheet1[Used Target])
VAR _NewT80 = SUM(Sheet1[New 80%])
VAR _UsedT80 = SUM(Sheet1[Used 80%])
VAR _AllSold= SUM(Sheet1[New Sold])+SUM(Sheet1[Used Sold])
VAR _AllTarget= SUM(Sheet1[New Target])+SUM(Sheet1[Used Target])
return
IF (
    AND (_NewSold >= _NewTarget ,_UsedSold >= _UsedTarget),
      _AllSold*150-_AllTarget*50 ,
    IF (
        OR (
            AND (_NewSold >=_NewTarget,_UsedSold >_UsedT80 ),
            AND (_NewSold >=_NewT80, _UsedSold>= _UsedTarget)
        ),
       _AllSold*100,
       _AllSold*25
    )
)

 

Result:

3.png

You can download the pbix file form this link:

https://qiuyunus-my.sharepoint.com/:u:/g/personal/tongzhou_qiuyunus_onmicrosoft_com/EWyRKsHutiRGgi1w...

 

Best Regards,

Rico Zhou

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

Brynieboy
Regular Visitor

 

 

Helpful resources

Announcements
August Power BI Update Carousel

Power BI Monthly Update - August 2025

Check out the August 2025 Power BI update to learn about new features.

August 2025 community update carousel

Fabric Community Update - August 2025

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

Top Solution Authors