In this blog post I provide with two different examples of school attendance excel sheets. Please comment and share your idea´s, feedback, improvements etc etc.

School attendance example 1

I created an excel template for creating a register of raw data (Date, school and attendees) and sum into monthly data.
See picture below.

school-attendees

I used the formula in this article

How to efficiently summarize data by category and month

and modified it: =SUMPRODUCT((YEAR($B$3:$B$200)=2008)*(MONTH($B$3:$B$200)=1)*($D$3:$D$200))

Download template
school-attendees.xls
(Excel 97-2003 Workbook *.xls)

Functions used in this article:

SUMPRODUCT(array1;array2;)
Returns the sum of the products of the corresponding ranges or arrays

YEAR(serial_number) returns the year of a date, an integer of the range 1900-9999

MONTH(serial_number) returns the month, a number from 1 (January) to 12 (December)

School attendance example 2

In this example I filter names using two date criteria. I then sum hours using the name and the two date criteria on an adjacent column.

Sheet "Data"

school attendance2

Sheet "Summary"

school attendance1

Array formula in A9:

=INDEX(Data!$A$2:$A$76, SMALL(IF(($B$3<=Data!$B$2:$B$76)*($B$4>=Data!$B$2:$B$76)*NOT(COUNTIF($A$8:A8, Data!$A$2:$A$76)), ROW(Data!$B$2:$B$76)-MIN(ROW(Data!$B$2:$B$76))+1), ROW($1:$1))) + CTRL + SHIFT + ENTER copied down as far as needed.

Array formula in B9:

=SUMPRODUCT(--($B$3<=Data!$B$2:$B$76), --($B$4>=Data!$B$2:$B$76), --(A9=Data!$A$2:$A$76), Data!$C$2:$C$76) + CTRL + SHIFT + ENTER copied down as far as needed.

Download excel file for this tutorial.

School attendee.xls
(Excel 97-2003 Workbook *.xls)

Functions in this article:

COUNTIF(range,criteria)
Counts the number of cells within a range that meet the given condition

MATCH(lookup_value;lookup_array; [match_type]
Returns the relative position of an item in an array that matches a specified value

INDEX(array,row_num,[column_num])
Returns a value or reference of the cell at the intersection of a particular row and column, in a given range

ROW(reference) returns the rownumber of a reference

SMALL(array,k) Returns the k-th smallest row number in this data set.

IF(logical_test;[value_if:true];[value_if_false])
Checks whether a condition is met, and returns one value if TRUE, and another value if FALSE

SUMPRODUCT(array1, array2, )
Returns the sum of the products of the corresponding ranges or arrays