How to create a list of field trips attended

pniven12

New Member
Joined
May 20, 2016
Messages
3
Hi - I'm a Gifted Education teacher that takes small groups of students on a ton of different field trips throughout the school year. Not all of the kids attend all of the trips.

At the end of the year, I'd like to create a list for each individual student of the field trips they attended for the year. Short of copying and pasting, is there an easier way?
I was thinking if I could use a drop down list that contained all of the field trips and another that contained the students, I would select one student, then select only the trips they attended, in the end creating a list of the students name and the trips attended so I can print out. :confused:

Currently I have the kids names in Cells A3-A30, the trips in D1-DF1, and a "1" in the cell if that student attended that trip. Hope this makes sense...... :eek:
 

Excel Facts

Which lookup functions find a value equal or greater than the lookup value?
MATCH uses -1 to find larger value (lookup table must be sorted ZA). XLOOKUP uses 1 to find values greater and does not need to be sorted.
Welcome to the forum.

If I understand correctly, your main sheet looks like this:
ABCDEFGHIJK
1NameZooMarine ParkHikingStock MarketComputer LabISSSealab
2
3Andy111111
4Beth111
5Cal111
6Dawn11
7Eric1111
8Felice111
9Gary111
10Halle11111
11
12

<tbody>
</tbody>
Sheet1



If so, you can set up a second sheet like this:

ABC
1NameTrips taken
2HalleMarine Park
3Hiking
4Stock Market
5ISS
6Sealab
7

<tbody>
</tbody>
Sheet2

Array Formulas
CellFormula
C2{=IF(C1="","",IFERROR(INDEX(Sheet1!$1:$1,SMALL(IF(OFFSET(Sheet1!$D$1:$DF$1,MATCH($A$2,Sheet1!$A$1:$A$30,0)-1,0)=1,COLUMN($D$1:$DF$1)),ROWS($C$2:$C2))),""))}

<tbody>
</tbody>
Entered with Ctrl+Shift+Enter. If entered correctly, Excel will surround with curly braces {}.
Note: Do not try and enter the {} manually yourself

<tbody>
</tbody>



In A2, set up a Data Validation set to List, with Source =Sheet1!$A$3:$A$30
Then you can select the student you want.

Put the heading in C1, then put the formula in C2, and confirm it with Control+Shift+Enter. Then copy that cell and paste it down the column as far as needed. Then all you have to do is select the student you want in A2 and the list will automatically populate in column C. Then print off that sheet and you're done.

Let me know if this is what you're looking for.

On further reflection, you could also create a macro that prints out the list automatically for all 30 students. If that's of interest, let me know.
 
Last edited:
Upvote 0
Welcome to the forum.

If I understand correctly, your main sheet looks like this:
ABCDEFGHIJK
1NameZooMarine ParkHikingStock MarketComputer LabISSSealab
2
3Andy111111
4Beth111
5Cal111
6Dawn11
7Eric1111
8Felice111
9Gary111
10Halle11111
11
12

<tbody>
</tbody>
Sheet1



If so, you can set up a second sheet like this:

ABC
1NameTrips taken
2HalleMarine Park
3Hiking
4Stock Market
5ISS
6Sealab
7

<tbody>
</tbody>
Sheet2

Array Formulas
CellFormula
C2{=IF(C1="","",IFERROR(INDEX(Sheet1!$1:$1,SMALL(IF(OFFSET(Sheet1!$D$1:$DF$1,MATCH($A$2,Sheet1!$A$1:$A$30,0)-1,0)=1,COLUMN($D$1:$DF$1)),ROWS($C$2:$C2))),""))}

<tbody>
</tbody>
Entered with Ctrl+Shift+Enter. If entered correctly, Excel will surround with curly braces {}.
Note: Do not try and enter the {} manually yourself

<tbody>
</tbody>



In A2, set up a Data Validation set to List, with Source =Sheet1!$A$3:$A$30
Then you can select the student you want.

Put the heading in C1, then put the formula in C2, and confirm it with Control+Shift+Enter. Then copy that cell and paste it down the column as far as needed. Then all you have to do is select the student you want in A2 and the list will automatically populate in column C. Then print off that sheet and you're done.

Let me know if this is what you're looking for.

On further reflection, you could also create a macro that prints out the list automatically for all 30 students. If that's of interest, let me know.
 
Upvote 0
Eric - THANK YOU SO MUCH! It's working like a charm! As for printing, I was just going to file, print. Everything fits onto one page for each of the kids.
Would it be difficult to create a registration list of those that signed up? I would imagine I would have the data validation set for the names. And then would need a list of the trips so that I have an attendance list the day of the trip....Maybe I'll stick to the way its set up now. I don't want to be a pain! :)

Thanks again! Your're awesome! (y)
 
Upvote 0
I'm glad it works for you!

Adding a registration list is just a matter of looking along the other axis. Set up another sheet like this:


Excel 2012
ABC
1TripEnrollees
2ISSBeth
3Dawn
4Eric
5Gary
6Halle
7
Sheet2
Cell Formulas
RangeFormula
C2{=IF(C1="","",IFERROR(INDEX(Sheet1!$A:$A,SMALL(IF(OFFSET(Sheet1!$D$3:$D$30,0,MATCH($A$2,Sheet1!$D$1:$DF$1,0)-1)=1,ROW($A$3:$A$30)),ROWS($C$2:$C2))),""))}
Press CTRL+SHIFT+ENTER to enter array formulas.


Set up Data Validation in A2 set to =Sheet1!$D1:$DF1. Then put the new formula in C2 confirmed with Control+Shift+Enter.

Good luck!
 
Upvote 0

Forum statistics

Threads
1,215,723
Messages
6,126,470
Members
449,315
Latest member
misterzim

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