"If" formula with mix of text and number to identify full days absent, or only hours absent

dctaillefer

New Member
Joined
Apr 27, 2019
Messages
4
Office Version
  1. 365
Platform
  1. Windows
I am working on a spreadsheet for timetracking/productivity. In one sheet (People), I have the employee's name in column A6:A26, and day of the week in row 4 (monday column c, tuesday column d, etc).
This "people" sheet is where it would identify what "V"acation days people are absent, or if they are taking off a couple of hours (ie. 2).

Trying to bring this information to another sheet in the workbook that assigns work, and want to account for absences. So either if person A has a "V" meaning the whole day is off, this sheet would account for the full 6.5 hours day to be accounted for, or if they had "2", then only 2 hours would be deducted.

This is the below formula that I have.... right now it is taking the full vacation days and bringing them to the new sheet, but for blanks or partial days it is returning an error.

=IF(INDEX(People!$C$6:$G$26,MATCH($A10,People!$A$6:$A$26,0),MATCH($B10,People!$C$4:$G$4,0))="V",6.5,(OFFSET(INDEX(People!$C$6:$G$26,MATCH($A10,People!$A$6:$A$26,0),MATCH($A10,People!$C$4:$G$4,0)),0,2)))

Attached are two screen shots; first one is of the "people" sheet, and the second is of the "assignments" page that has the errors. Any help with why I'm getting an error would be greatly appreciated.

1675946852544.png
1675946893034.png
 

Excel Facts

Copy formula down without changing references
If you have =SUM(F2:F49) in F50; type Alt+' in F51 to copy =SUM(F2:F49) to F51, leaving the formula in edit mode. Change SUM to COUNT.
What version of Excel are you using?

I suggest that you update your Account details (or click your user name at the top right of the forum) so helpers always know what Excel version(s) & platform(s) you are using as the best solution often varies by version. (Don’t forget to scroll down & ‘Save’)
 
Upvote 0
What version of Excel are you using?

I suggest that you update your Account details (or click your user name at the top right of the forum) so helpers always know what Excel version(s) & platform(s) you are using as the best solution often varies by version. (Don’t forget to scroll down & ‘Save’)
Using 365, on Windows. I've updated my account details.
 
Upvote 0
Thanks for that. (y)
How about
Excel Formula:
=LET(a,INDEX(People!$C$6:$G$26,MATCH($A10,People!$A$6:$A$26,0),MATCH($B10,People!$C$4:$G$4,0)),IF(a="V",6.5,IF(a="","",a)))
 
Upvote 1
Solution
Thanks for that. (y)
How about
Excel Formula:
=LET(a,INDEX(People!$C$6:$G$26,MATCH($A10,People!$A$6:$A$26,0),MATCH($B10,People!$C$4:$G$4,0)),IF(a="V",6.5,IF(a="","",a)))
Amazing. Thank you so much. That works.
 
Upvote 0
You're welcome & thanks for the feedback.
 
Upvote 0

Forum statistics

Threads
1,214,639
Messages
6,120,679
Members
448,977
Latest member
dbonilla0331

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