Skip to content

Commit

Permalink
Updated for 2017 requirements
Browse files Browse the repository at this point in the history
  • Loading branch information
neurotech committed Mar 23, 2017
1 parent 1a660bf commit cb619ed
Show file tree
Hide file tree
Showing 5 changed files with 65 additions and 22 deletions.
30 changes: 27 additions & 3 deletions sql/staff/staff-information-sheet_00_mainquery.sql
@@ -1,4 +1,6 @@
WITH cars AS (
WITH report_vars AS (SELECT '[[Due by=date]]' AS "DEADLINE" FROM SYSIBM.sysdummy1),

cars AS (
SELECT
contact_id,
LISTAGG(COALESCE(car_make, '') || ' ' || COALESCE(car_model, '') || ' (' || COALESCE(car_rego, '') || ')', ', ') WITHIN GROUP(ORDER BY car_make, car_model, car_rego) AS "CARS"
Expand All @@ -13,9 +15,13 @@ STAFFBASE AS
SELECT
STAFF_NUMBER,
CONTACT.CONTACT_ID,
salutation.salutation,
CONTACT.SURNAME,
CONTACT.FIRSTNAME,
CONTACT.PREFERRED_NAME,
CONTACT.BIRTHDATE,
gender.gender,
house.house,
GROUPS.GROUPS,
(CASE
WHEN VIEW_CONTACT_HOME_ADDRESS.ADDRESS1 = ''
Expand All @@ -28,13 +34,16 @@ STAFFBASE AS
VIEW_CONTACT_POSTAL_ADDRESS.PHONE
) AS "HOME_PHONE",
CONTACT.MOBILE_PHONE,
work_type.work_type AS "OCCUPATION",
work_detail.title,
CARS.CARS,
CONTACT.BIRTHDATE,
SE.EMPLOYMENT_TYPE_ID,
EMPLOYMENT_TYPE.EMPLOYMENT_TYPE,
SE.START_DATE,
SE.END_DATE,
CONTACT_QUALIFICATION.YEAR_TEACHING AS "YEAR_TEACHING",
CONTACT_QUALIFICATION.YEAR_TEACHING,
CONTACT_QUALIFICATION.YEAR_TEACH_AUSTRALIA,
CONTACT_QUALIFICATION.YEAR_TEACH_STATE,
CONTACT_QUALIFICATION.YEAR_TEACH_SCHOOL AS "YEAR_TEACHING_ROSEBANK",
CONTACT.WWC_NUMBER,
CONTACT.WWC_EXPIRY_DATE,
Expand All @@ -43,16 +52,23 @@ STAFFBASE AS
FROM STAFF

INNER JOIN CONTACT ON CONTACT.CONTACT_ID = STAFF.CONTACT_ID
INNER JOIN salutation ON salutation.salutation_id = contact.salutation_id
INNER JOIN gender ON gender.gender_id = contact.gender_id
INNER JOIN house ON house.house_id = staff.house_id

INNER JOIN GROUP_MEMBERSHIP ON GROUP_MEMBERSHIP.CONTACT_ID = STAFF.CONTACT_ID
INNER JOIN GROUPS ON GROUPS.GROUPS_ID = GROUP_MEMBERSHIP.GROUPS_ID AND (GROUPS.GROUPS_ID = 386)

LEFT JOIN VIEW_CONTACT_DEFAULT_ADDRESS ON VIEW_CONTACT_DEFAULT_ADDRESS.CONTACT_ID = STAFF.CONTACT_ID
LEFT JOIN VIEW_CONTACT_HOME_ADDRESS ON VIEW_CONTACT_HOME_ADDRESS.CONTACT_ID = STAFF.CONTACT_ID
LEFT JOIN VIEW_CONTACT_POSTAL_ADDRESS ON VIEW_CONTACT_POSTAL_ADDRESS.CONTACT_ID = STAFF.CONTACT_ID
LEFT JOIN VIEW_CONTACT_WORK_ADDRESS ON VIEW_CONTACT_WORK_ADDRESS.CONTACT_ID = STAFF.CONTACT_ID

LEFT JOIN CARS ON CARS.CONTACT_ID = STAFF.CONTACT_ID
LEFT JOIN STAFF_EMPLOYMENT SE ON STAFF.STAFF_ID = SE.STAFF_ID
LEFT JOIN EMPLOYMENT_TYPE ON EMPLOYMENT_TYPE.EMPLOYMENT_TYPE_ID = SE.EMPLOYMENT_TYPE_ID
LEFT JOIN WORK_DETAIL ON WORK_DETAIL.CONTACT_ID = STAFF.CONTACT_ID
LEFT JOIN work_type ON work_type.work_type_id = work_detail.work_type_id

LEFT JOIN religion ON religion.religion_id = contact.religion_id

Expand All @@ -79,17 +95,25 @@ STAFFBASE AS
SELECT
STAFFBASE.CONTACT_ID,
STAFFBASE.STAFF_NUMBER,
(SELECT TO_CHAR(deadline, 'Day DD Month') FROM report_vars) AS "DEADLINE",
salutation,
SURNAME,
FIRSTNAME,
(CASE WHEN PREFERRED_NAME IS NULL THEN NULL ELSE '(' || PREFERRED_NAME || ')' END) AS "PREFERRED_NAME",
gender,
house,
EMPLOYMENT_TYPE,
occupation,
title,
HOME_ADDRESS,
HOME_PHONE,
MOBILE_PHONE,
CARS,
TO_CHAR(BIRTHDATE, 'Month DD, YYYY') as "BIRTHDATE",
religion,
YEAR_TEACHING,
YEAR_TEACH_AUSTRALIA,
YEAR_TEACH_STATE,
YEAR_TEACHING_ROSEBANK,
TO_CHAR(START_DATE, 'Month DD, YYYY') as "START_DATE",
END_DATE,
Expand Down
11 changes: 3 additions & 8 deletions sql/staff/staff-information-sheet_01_qualifications.sql
@@ -1,24 +1,19 @@
WITH QUALS_RAW AS
(
SELECT
STAFF.STAFF_NUMBER,
QUALIFICATION,
QUALIFICATION_TYPE.QUALIFICATION_TYPE,
institute.institute AS "QUALIFICATION_INSTITUTE",
TO_CHAR(QYEAR) AS "QYEAR"

FROM QUALIFICATION

LEFT JOIN CONTACT ON CONTACT.CONTACT_ID = QUALIFICATION.CONTACT_ID
LEFT JOIN STAFF ON QUALIFICATION.CONTACT_ID = STAFF.CONTACT_ID
LEFT JOIN QUALIFICATION_TYPE ON QUALIFICATION_TYPE.QUALIFICATION_TYPE_ID = QUALIFICATION.QUALIFICATION_TYPE_ID
LEFT JOIN institute ON institute.institute_id = qualification.institute_id

WHERE CONTACT.CONTACT_ID = [[mainquery.contact_id]]
)

SELECT
STAFF_NUMBER,
LISTAGG(QUALIFICATION || ' (' || QUALIFICATION_TYPE || ' - ' || CASE WHEN QYEAR IS NULL THEN 'Year Unknown' ELSE QYEAR END || ')', ', ') WITHIN GROUP(ORDER BY STAFF_NUMBER) "ALL_QUALIFICATIONS"

FROM QUALS_RAW

GROUP BY STAFF_NUMBER
SELECT * FROM quals_raw ORDER BY QYEAR DESC
42 changes: 33 additions & 9 deletions sql/staff/staff-information-sheet_02_courses.sql
Expand Up @@ -2,26 +2,50 @@ WITH TRAINING_COURSES_RAW AS
(
SELECT
STAFF.STAFF_NUMBER,
STAFF_COURSE.DETAILS || ' (' || TO_CHAR(STAFF_COURSE.STARTDATE, 'DD Month YYYY') || ')' AS "DETAILS"
staff_course.staff_course AS "COURSE",
STAFF_COURSE.details,
staff_course.hours,
TO_CHAR(staff_course.startdate, 'DD Mon YYYY') AS "START_DATE",
TO_CHAR(staff_course.enddate, 'DD Mon YYYY') AS "END_DATE",
institute.institute,
STAFF_COURSE.startdate

FROM STAFF_COURSE

LEFT JOIN CONTACT ON CONTACT.CONTACT_ID = STAFF_COURSE.CONTACT_ID
LEFT JOIN STAFF ON STAFF_COURSE.CONTACT_ID = STAFF.CONTACT_ID
LEFT JOIN institute ON institute.institute_id = staff_course.institute_id

WHERE CONTACT.CONTACT_ID = [[mainquery.contact_id]]
AND STARTDATE > (current_date - 1 YEAR)
WHERE
CONTACT.CONTACT_ID = [[mainquery.contact_id]]
AND DETAILS IS NOT NULL
AND STAFF_COURSE IS NOT NULL
AND DETAILS NOT LIKE '$%'
AND DETAILS NOT LIKE 'Free'
AND DETAILS NOT LIKE 'nil'
),

total_hours_this_year AS (
SELECT
staff_number,
SUM(hours) AS "HOURS"

FROM training_courses_raw

WHERE YEAR(startdate) = YEAR(current date)

GROUP BY staff_number
)

SELECT
STAFF_NUMBER,
LISTAGG(DETAILS, ', ') WITHIN GROUP(ORDER BY STAFF_NUMBER) "ALL_COURSES"
TRAINING_COURSES_RAW.staff_number,
CHAR(COALESCE(total_hours_this_year.hours, 0)) AS "HOURS_THIS_YEAR",
training_courses_raw.course,
training_courses_raw.details,
CHAR(training_courses_raw.hours) AS "HOURS",
training_courses_raw.start_date,
training_courses_raw.end_date,
COALESCE(training_courses_raw.institute, '') AS "INSTITUTE"

FROM TRAINING_COURSES_RAW

GROUP BY STAFF_NUMBER
LEFT JOIN total_hours_this_year ON total_hours_this_year.staff_number = training_courses_raw.staff_number

ORDER BY startdate DESC
4 changes: 2 additions & 2 deletions sql/staff/staff-information-sheet_03_emergency.sql
Expand Up @@ -2,8 +2,8 @@ SELECT
STAFF_NUMBER,
C2.FIRSTNAME || ' ' || C2.SURNAME AS "EMERGENCY_CONTACT_NAME",
CASE WHEN RELATIONSHIP_TYPE.RELATIONSHIP_TYPE IS NOT NULL THEN '(' || RELATIONSHIP_TYPE.RELATIONSHIP_TYPE || ')' ELSE NULL END AS "EMERGENCY_CONTACT_RELATION",
CASE WHEN HOME2.PHONE != '' THEN 'Home: ' || HOME2.PHONE || (CASE WHEN WP2.PHONE IS NOT NULL OR C2.MOBILE_PHONE IS NOT NULL THEN ' | ' ELSE '' END) ELSE '' END ||
CASE WHEN WP2.PHONE IS NOT NULL THEN 'Work: ' || '(' || WP2.AREA_CODE || ')' || WP2.PHONE || (CASE WHEN C2.MOBILE_PHONE IS NOT NULL THEN ' | ' ELSE '' END) ELSE '' END ||
CASE WHEN HOME2.PHONE != '' THEN 'Home: ' || HOME2.PHONE || (CASE WHEN WP2.PHONE IS NOT NULL OR C2.MOBILE_PHONE IS NOT NULL THEN ' <br> ' ELSE '' END) ELSE '' END ||
CASE WHEN WP2.PHONE IS NOT NULL THEN 'Work: ' || '(' || WP2.AREA_CODE || ')' || WP2.PHONE || (CASE WHEN C2.MOBILE_PHONE IS NOT NULL THEN ' <br> ' ELSE '' END) ELSE '' END ||
CASE WHEN C2.MOBILE_PHONE IS NOT NULL THEN 'Mobile: ' || C2.MOBILE_PHONE ELSE '' END AS "EMERGENCY_NUMBERS"

FROM STAFF
Expand Down
Binary file modified templates/staff/staff-information-sheet.sxw
Binary file not shown.

0 comments on commit cb619ed

Please sign in to comment.