| 1 | == Напредни Процедури |
| 2 | === 1. Складирана процедура за додавање на на нов MedicalReport објект за конкретен Person запис |
| 3 | {{{ |
| 4 | CREATE OR REPLACE PROCEDURE insert_medical_report( |
| 5 | IN param_person_id INT, |
| 6 | IN param_summary TEXT, |
| 7 | IN param_doctor_id INT, |
| 8 | IN param_next_control_date DATE, |
| 9 | IN param_diagnosis_ids INT[] |
| 10 | ) |
| 11 | LANGUAGE plpgsql |
| 12 | AS |
| 13 | $$ |
| 14 | DECLARE |
| 15 | new_report_id INT; |
| 16 | variable_diagnosis_id INT; |
| 17 | BEGIN |
| 18 | IF NOT EXISTS (SELECT 1 |
| 19 | FROM person |
| 20 | WHERE person_id = param_person_id) THEN |
| 21 | RAISE EXCEPTION 'Person with ID % does not exist', param_person_id; |
| 22 | END IF; |
| 23 | IF NOT EXISTS (SELECT 1 FROM doctor WHERE doctor_id = param_doctor_id) THEN |
| 24 | RAISE EXCEPTION 'Doctor with ID % does not exist', param_doctor_id; |
| 25 | END IF; |
| 26 | |
| 27 | INSERT INTO report (report_type, summary, created_at, person_id) |
| 28 | VALUES ('Medical', param_summary, CURRENT_TIMESTAMP, param_person_id) |
| 29 | RETURNING report_id INTO new_report_id; |
| 30 | |
| 31 | INSERT INTO medicalreport (report_id, doctor_id, next_control_date) |
| 32 | VALUES (new_report_id, param_doctor_id, param_next_control_date); |
| 33 | |
| 34 | IF param_diagnosis_ids IS NOT NULL THEN |
| 35 | FOREACH variable_diagnosis_id IN ARRAY param_diagnosis_ids |
| 36 | LOOP |
| 37 | IF NOT EXISTS (SELECT 1 FROM diagnosis WHERE variable_diagnosis_id = variable_diagnosis_id) THEN |
| 38 | RAISE EXCEPTION 'Diagnosis ID % does not exist', variable_diagnosis_id; |
| 39 | END IF; |
| 40 | INSERT INTO medicalreport_diagnosis (report_id, diagnosis_id, added_on) |
| 41 | VALUES (new_report_id, variable_diagnosis_id, CURRENT_TIMESTAMP); |
| 42 | END LOOP; |
| 43 | END IF; |
| 44 | END; |
| 45 | $$; |
| 46 | }}} |
| 47 | |
| 48 | === 2. Складирана процедура за додавање на на нов EmploymentReport објект за конкретен Person запис |
| 49 | {{{ |
| 50 | CREATE OR REPLACE PROCEDURE insert_employment_report( |
| 51 | IN param_person_id INT, |
| 52 | IN param_start_date DATE, |
| 53 | IN param_end_date DATE, |
| 54 | IN param_job_role TEXT, |
| 55 | IN param_income NUMERIC, |
| 56 | IN param_summary TEXT |
| 57 | ) |
| 58 | LANGUAGE plpgsql |
| 59 | AS |
| 60 | $$ |
| 61 | DECLARE |
| 62 | new_report_id INT; |
| 63 | BEGIN |
| 64 | IF NOT EXISTS (SELECT 1 |
| 65 | FROM person |
| 66 | WHERE person_id = param_person_id) THEN |
| 67 | RAISE EXCEPTION 'Person with ID % does not exist', param_person_id; |
| 68 | END IF; |
| 69 | |
| 70 | IF param_end_date is not null and param_end_date < param_start_date then |
| 71 | raise exception 'End date can not be before starting date'; |
| 72 | end if; |
| 73 | |
| 74 | IF param_income is not null and param_income <= 0 then |
| 75 | raise exception 'Income must be greater than 0'; |
| 76 | end if; |
| 77 | |
| 78 | INSERT INTO report (report_type, summary, created_at, person_id) |
| 79 | VALUES ('Employment', param_summary, CURRENT_TIMESTAMP, param_person_id) |
| 80 | RETURNING report_id INTO new_report_id; |
| 81 | |
| 82 | INSERT INTO employmentreport (report_id, start_date, end_date, job_role, income_per_month) |
| 83 | VALUES (new_report_id, |
| 84 | param_start_date, |
| 85 | param_end_date, |
| 86 | param_job_role, |
| 87 | param_income); |
| 88 | END; |
| 89 | $$; |
| 90 | }}} |
| 91 | |
| 92 | === 3. Складирана процедура за додавање на на нов CriminalReport објект за конкретен Person запис |
| 93 | {{{ |
| 94 | CREATE OR REPLACE PROCEDURE insert_criminal_report( |
| 95 | IN param_person_id INT, |
| 96 | IN param_case_summary TEXT, |
| 97 | IN param_location TEXT, |
| 98 | IN param_is_resolved BOOLEAN, |
| 99 | IN param_crime_type_id INT, |
| 100 | IN param_punishment_type TEXT, |
| 101 | IN param_fine_to_pay NUMERIC, |
| 102 | IN param_release_date DATE |
| 103 | ) |
| 104 | LANGUAGE plpgsql |
| 105 | AS |
| 106 | $$ |
| 107 | DECLARE |
| 108 | new_report_id INT; |
| 109 | new_punishment_id INT; |
| 110 | BEGIN |
| 111 | IF NOT EXISTS (SELECT 1 |
| 112 | FROM person |
| 113 | WHERE person_id = param_person_id) THEN |
| 114 | RAISE EXCEPTION 'Person with ID % does not exist', param_person_id; |
| 115 | END IF; |
| 116 | |
| 117 | IF NOT EXISTS (SELECT 1 |
| 118 | FROM crimetype |
| 119 | WHERE crime_type_id = param_crime_type_id) THEN |
| 120 | RAISE EXCEPTION 'CrimeType with ID % does not exist', param_crime_type_id; |
| 121 | END IF; |
| 122 | |
| 123 | INSERT INTO report (report_type, summary, created_at, person_id) |
| 124 | VALUES ('Criminal', param_case_summary, CURRENT_TIMESTAMP, param_person_id) |
| 125 | RETURNING report_id INTO new_report_id; |
| 126 | |
| 127 | INSERT INTO criminalreport (report_id, location, resolved, crime_type_id) |
| 128 | VALUES (new_report_id, param_location, param_is_resolved, param_crime_type_id); |
| 129 | |
| 130 | IF param_punishment_type = 'PRISON' AND param_release_date IS NOT NULL THEN |
| 131 | INSERT INTO punishment (report_id, value_unit, punishment_type, fine_to_pay, release_date) |
| 132 | VALUES (new_report_id, 'years', LOWER(param_punishment_type), NULL, param_release_date) |
| 133 | RETURNING punishment_id INTO new_punishment_id; |
| 134 | END IF; |
| 135 | |
| 136 | IF param_punishment_type = 'FINE' AND param_fine_to_pay IS NOT NULL THEN |
| 137 | INSERT INTO punishment (report_id, value_unit, punishment_type, fine_to_pay, release_date) |
| 138 | VALUES (new_report_id, 'euros', LOWER(param_punishment_type), param_fine_to_pay, NULL) |
| 139 | RETURNING punishment_id INTO new_punishment_id; |
| 140 | END IF; |
| 141 | |
| 142 | END; |
| 143 | $$; |
| 144 | }}} |
| 145 | |
| 146 | === 4. Складирана процедура за додавање на на нов AcademicReport објект за конкретен Person запис |
| 147 | {{{ |
| 148 | CREATE OR REPLACE PROCEDURE insert_academic_report( |
| 149 | IN param_person_id INT, |
| 150 | IN param_institution_id INT, |
| 151 | IN param_academic_field TEXT, |
| 152 | IN param_description_of_report TEXT |
| 153 | ) |
| 154 | LANGUAGE plpgsql |
| 155 | as |
| 156 | $$ |
| 157 | DECLARE |
| 158 | new_report_id INT; |
| 159 | BEGIN |
| 160 | IF NOT EXISTS (SELECT 1 |
| 161 | FROM person |
| 162 | WHERE person_id = param_person_id) THEN |
| 163 | RAISE EXCEPTION 'Person with ID % does not exist', param_person_id; |
| 164 | END IF; |
| 165 | IF NOT EXISTS (SELECT 1 |
| 166 | FROM institution |
| 167 | WHERE institution_id = param_institution_id) THEN |
| 168 | RAISE EXCEPTION 'Institution with ID % does not exist', param_institution_id; |
| 169 | END IF; |
| 170 | |
| 171 | INSERT INTO report (report_type, summary, created_at, person_id) |
| 172 | VALUES ('Academic', param_description_of_report, CURRENT_TIMESTAMP, param_person_id) |
| 173 | RETURNING report_id INTO new_report_id; |
| 174 | |
| 175 | INSERT INTO academicreport (report_id, institution_id, academic_field, description_of_report) |
| 176 | VALUES (new_report_id, param_institution_id, param_academic_field, param_description_of_report); |
| 177 | END; |
| 178 | $$; |
| 179 | }}} |