Look Up and Cell Reference - Formula Help Needed

G

Guest

Help - Need Formula
I am working on an employee scheduling matrix. I have a spreadsheet with
days of the week across the columns and start times down the rows. I fill in
the name of the employee coming in at each start time each day of the week.

I would like excel to automatically create a table in another worksheet that
will list days of the week in the columns, employee names in the rows, and
look up each employee's start time for each day and fill it in, in the
appropriate row/column.

Does this make sense? Help!
 
M

Max

Perhaps something along these lines ..

In Sheet1
-------------
The sample table below is in A1:H6
where employee's initials are entered
depending on their scheduled start times
per day of the week

Time Mon Tue Wed Thu Fri Sat Sun
7:00 AM PT GL MK MK MK MX MK
7:30 AM GL KK KK GL MX KK KK
8:00 AM MK MK GL KK GL GL PT
8:30 AM KK MX PT PT PT MK MX
9:00 AM MX PT MX MX KK PT GL

(It's assumed that only 1 employee would be scheduled
per start time per day of week)

In Sheet2
-------------
You want to populate the table below in A1:H6
with the start times of each employee by day of week,
where the employees initials are listed in A2:AA6

Emp Mon Tue Wed Thu Fri Sat Sun
MK
GL
MX
KK
PT

Put in B2:

=IF(ISNA(MATCH($A2,Sheet1!B:B,0)),"",INDEX(Sheet1!$A:$A,MATCH($A2,Sheet1!B:B
,0)))

Format B2 as Time (Type: "1:30 PM")

Copy B2 across to H2, fill down to H6 to populate the table

This'll return all the start times from Sheet1,
viz, for the sample data in Sheet1, you'll get:

Emp Mon Tue Wed Thu Fri Sat Sun
MK 8:00 AM 8:00 AM 7:00 AM 7:00 AM 7:00 AM 8:30 AM 7:00 AM
GL 7:30 AM 7:00 AM 8:00 AM 7:30 AM 8:00 AM 8:00 AM 9:00 AM
MX 9:00 AM 8:30 AM 9:00 AM 9:00 AM 7:30 AM 7:00 AM 8:30 AM
KK 8:30 AM 7:30 AM 7:30 AM 8:00 AM 9:00 AM 7:30 AM 7:30 AM
PT 7:00 AM 9:00 AM 8:30 AM 8:30 AM 8:30 AM 9:00 AM 8:00 AM
 

Ask a Question

Want to reply to this thread or ask your own question?

You'll need to choose a username for the site, which only take a couple of moments. After that, you can post your question and our members will help you out.

Ask a Question

Top