Calculate percentage for specific cell based on sum of a range

rugby_nut

New Member
Joined
Jan 13, 2009
Messages
42
Hi all,

I have a simple spreadsheet that calculates daily performance rates, using the actual daily scores in E3 to I3, divided by the target score in D3, which returns the result in K3 to O3. See below.
However, if the overall schedule is met in less than a week, the day this is met (Thu), the performance rate is reduced as N3 is calculating against the daily target D3.
Is there a way to calculate this percentage so it works out against the remaining balance on that day?
To note, sometimes the final number for the daily score can be over the amount required to fulfil the schedule, so if H3 was >47 N3 would show >100%.

Thank you..

Screenshot 2022-05-24 at 18.17.03.png
 

Excel Facts

What is the shortcut key for Format Selection?
Ctrl+1 (the number one) will open the Format dialog for whatever is selected.
if( SUM($E$3:E3)/$A3 > = 1 , 100% , E3/$D$3 )
so if the value of the week to date is greater then 400 , then 100%

is that the sort of thing you meant

BUT an image does mean entering all the example myself

Book1
ABCDEFGHIJKLMNO
1
2SchedulecompleteremainingTargetMonTueWedThuFriMonTueWedThuFri
340040001351201101234789%81%91%100%100%
Sheet1
Cell Formulas
RangeFormula
K3:M3K3=IF(SUM($E$3:E3)/$A3>1,100%,E3/$D$3)
N3:O3N3=IF(SUM($E$3:H3)/$A3>=1,100%,H3/$D$3)


meanwhile
Note: Images are difficult to see , and also requires that I input all the data myself, which is very time consuming.

A SMALL sample spreadsheet, around 10-20 rows, would help a lot here, with all sensitive data removed, and expected results mocked up and manually entered, with a few notes of explanation.

MrExcel has a tool called “XL2BB” that lets you post samples of your data and will allow us to copy/paste your sample data into our Excel spreadsheets, saving a lot of time.

You can also test to see if it works ok, in the "Test Here" forum.

OR if you cannot get XL2BB to work, or have restrictions on your PC , then put the sample spreadsheet onto a share
I only tend to goto OneDrive, Dropbox or google docs , as I'm never certain of other random share sites and possible virus.
Please make sure you have a representative data sample and also that the data has been desensitised, remember this site is open to anyone with internet access to see - so any sensitive / personal data should be removed
 
Upvote 0
Thank you for the quick response. Here's the XL2BB download.

Book1
ABCDEFGHIJKLMNO
1Daily ScoreDaily Performance
2ScheduleCompletedRemainingTargetMonTueWedThuFriMonTueWedThuFri
340040001351201101234789%81%91%35%0%
Sheet1
Cell Formulas
RangeFormula
B3B3=SUM(E3:I3)
C3C3=A3-B3
K3:O3K3=IF(SUM($E$3:E3)/$A3>1,100%,E3/$D$3)
 
Upvote 0
correction as i see the formula is not the same across K to O
and should be
=IF(SUM($E$3:E3)/$A3>=1,100%,E3/$D$3)
Or did you want once archived 100% , then show the weeks performance against week target - see 2nd XL2BB below

=IF(SUM($E$3:E3)/$A3>=1,SUM($E$3:E3)/$A3,E3/$D$3)
capped art 100%

Book1
ABCDEFGHIJKLMNO
1
2SchedulecompleteremainingTargetMonTueWedThuFriMonTueWedThuFri
340040001351201101234789%81%91%100%100%
Sheet1
Cell Formulas
RangeFormula
K3:O3K3=IF(SUM($E$3:E3)/$A3>=1,100%,E3/$D$3)


showing above 100%

Book1
ABCDEFGHIJKLMNO
1
2SchedulecompleteremainingTargetMonTueWedThuFriMonTueWedThuFri
340040001351201101234710089%81%91%100%125%
Sheet1
Cell Formulas
RangeFormula
K3:O3K3=IF(SUM($E$3:E3)/$A3>=1,SUM($E$3:E3)/$A3,E3/$D$3)
 
Upvote 0
Thank you. Running over 100% is ok, so if 60 units were made on Thursday the performance would be 103% which is fine.

If there were 47 units remaining on Thursday and the score reached exactly 47 then the performance would be 100% which is also fine. However, the performance in Friday also shows 100% but there was no production. If I were to take the weeks overall performance, this result would make the weekly answer incorrect. Is there a way to not calculate any remaining days if there is no score recorded?
I hope that makes sense?
 
Upvote 0
how about
=IF(E3="","",IF(SUM($E$3:E3)/$A3>=1,SUM($E$3:E3)/$A3,E3/$D$3))

Book1
ABCDEFGHIJKLMNO
1
2SchedulecompleteremainingTargetMonTueWedThuFriMonTueWedThuFri
340040001351201101236089%81%91%103% 
Sheet1
Cell Formulas
RangeFormula
K3:O3K3=IF(E3="","",IF(SUM($E$3:E3)/$A3>=1,SUM($E$3:E3)/$A3,E3/$D$3))
 
Upvote 0
Solution
how about
=IF(E3="","",IF(SUM($E$3:E3)/$A3>=1,SUM($E$3:E3)/$A3,E3/$D$3))

Book1
ABCDEFGHIJKLMNO
1
2SchedulecompleteremainingTargetMonTueWedThuFriMonTueWedThuFri
340040001351201101236089%81%91%103% 
Sheet1
Cell Formulas
RangeFormula
K3:O3K3=IF(E3="","",IF(SUM($E$3:E3)/$A3>=1,SUM($E$3:E3)/$A3,E3/$D$3))
That worked a dream! Thank you again :)(y)
 
Upvote 0

Forum statistics

Threads
1,215,488
Messages
6,125,092
Members
449,206
Latest member
ralemanygarcia

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
Back
Top