Help with IF and SUM range with VLOOKUP...

pete234

Active Member
Joined
Feb 10, 2004
Messages
419
I am learning that doing these by level is helpful but only so much for me.

=J4/SUM(Budget!D2:F2)

This will look at actual sold value and divide by the sum range for first quarter in another sheet.
But I need it to VLOOKUP from I4 to the Budget Page to match employee name.
(Budget page has names in rows, budget in values, months across columns.)
And reference the fiscal Qtr in Column C so that I return the budget vs actual from correct period on second page.
Meaning if Fiscal Quarter in first page is 1, divide by sum D_:F__, if it's 2 then divide by sum G:I etc for the person it matches.
I was dividing out from a Month calculation but this proved to be a few percent off annually.

Appreciate any ideas how to write this.
 
Last edited:

Some videos you may like

Excel Facts

Remove leading & trailing spaces
Save as CSV to remove all leading and trailing spaces. It is faster than using TRIM().

pete234

Active Member
Joined
Feb 10, 2004
Messages
419
Employee names are in both sheets. In Sales Sheet in column I in Budget sheet column B.
Here is what the data looks like.
So I need to divide sales by the sum of the right Quarter in budget to get actual %.
Budget Sheet
B C D E F G H
Employee/Month 1 2 3 4 5 6
Employee 1 10000 12500 15000 15000 15000 15000
Employee 2 10000 12500 15000 15000 15000 15000
Employee 3 15000 17500 20000 20000 20000 20000


Sales Sheet
Quarter Number Sales
1 Employee 1 150
1 Employee 1 2000
1 Employee 2 1000
1 Employee 1 850
2 Employee 1 1500
2 Employee 2 750
3 Employee 3 1000
 

Andrew Poulsom

MrExcel MVP
Joined
Jul 21, 2002
Messages
73,092
Try this formula in C2 copied down:

=SUMPRODUCT((Budget!B$2:B$4=B2)*(Budget!C$2:H$4)*(Budget!C$1:H$1<=(A2*3))*(Budget!C$1:H$1>((A2-1)*3)))
 

Watch MrExcel Video

Forum statistics

Threads
1,123,281
Messages
5,600,720
Members
414,401
Latest member
grenona2020

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Top