| 10 | |
| 11 | **Дополнителен дел со статистики** |
| 12 | |
| 13 | Овој дел прикажува статистики за сите видови извештаи поврзани со избраната личност. Статистиките се прикажани во долниот дел од страницата и даваат преглед од сите извештаи. |
| 14 | |
| 15 | ==== SQL queries кои се користат за да се извлечат податоците ==== |
| 16 | |
| 17 | 1. Квери за прикажување на сите извештаи за персоната во табелите |
| 18 | |
| 19 | {{{ |
| 20 | --academic reports |
| 21 | |
| 22 | SELECT r.report_id, academic_field, description_of_report, i.name, i.type, i.address, i.year_established |
| 23 | FROM report r |
| 24 | JOIN academicreport ar ON ar.report_id = r.report_id |
| 25 | JOIN institution i ON i.institution_id = ar.institution_id |
| 26 | WHERE r.person_id = :personId |
| 27 | |
| 28 | --employment reports |
| 29 | |
| 30 | SELECT r.report_id, summary, er.start_date, er.end_date, job_role, income_per_month |
| 31 | FROM report r |
| 32 | JOIN employmentreport er ON er.report_id = r.report_id |
| 33 | WHERE r.person_id = :personId |
| 34 | |
| 35 | --medical reports |
| 36 | |
| 37 | SELECT r.report_id, summary, next_control_date, d.short_description, d.therapy, d.severity, d.is_chronic, |
| 38 | doc.name, doc.surname, doc.specialization |
| 39 | FROM report r |
| 40 | JOIN medicalreport mr ON mr.report_id = r.report_id |
| 41 | JOIN medicalreport_diagnosis mrd ON mr.report_id = mrd.report_id |
| 42 | JOIN diagnosis d ON mrd.diagnosis_id = d.diagnosis_id |
| 43 | JOIN doctor doc ON doc.doctor_id = mr.doctor_id |
| 44 | WHERE r.person_id = :personId |
| 45 | |
| 46 | --criminal reports |
| 47 | |
| 48 | SELECT r.report_id, label, severity_level, location, resolved, descriptive_punishment |
| 49 | FROM report r |
| 50 | JOIN criminalreport cr ON cr.report_id = r.report_id |
| 51 | JOIN crimetype ct ON cr.crime_type_id = ct.crime_type_id |
| 52 | WHERE r.person_id = :personId |
| 53 | }}} |
| 54 | |
| 55 | 2. Квери за статистиките на персоната |
| 56 | |
| 57 | {{{ |
| 58 | WITH |
| 59 | selected_person_reports AS ( |
| 60 | SELECT * FROM report WHERE person_id = :person_id |
| 61 | ), |
| 62 | |
| 63 | academic AS ( |
| 64 | SELECT r.created_at, ar.academic_field, ar.report_id |
| 65 | FROM report r |
| 66 | JOIN academicreport ar ON r.report_id = ar.report_id |
| 67 | JOIN institution i ON i.institution_id = ar.institution_id |
| 68 | WHERE r.person_id = :person_id |
| 69 | ), |
| 70 | |
| 71 | employment AS ( |
| 72 | SELECT e.start_date, COALESCE(e.end_date, CURRENT_DATE) AS end_date, e.income_per_month |
| 73 | FROM employmentreport e |
| 74 | JOIN report r ON r.report_id = e.report_id |
| 75 | WHERE r.person_id = :person_id |
| 76 | ), |
| 77 | |
| 78 | medical AS ( |
| 79 | SELECT d.short_description, d.is_chronic |
| 80 | FROM report r |
| 81 | JOIN medicalreport mr ON r.report_id = mr.report_id |
| 82 | JOIN medicalreport_diagnosis mrd ON mrd.report_id = mr.report_id |
| 83 | JOIN diagnosis d ON d.diagnosis_id = mrd.diagnosis_id |
| 84 | WHERE r.person_id = :person_id |
| 85 | ), |
| 86 | |
| 87 | criminal AS ( |
| 88 | SELECT cr.descriptive_punishment, cr.resolved as is_resolved |
| 89 | FROM report r |
| 90 | JOIN criminalreport cr ON r.report_id = cr.report_id |
| 91 | JOIN crimetype ct ON ct.crime_type_id = cr.crime_type_id |
| 92 | WHERE r.person_id = :person_id |
| 93 | ), |
| 94 | |
| 95 | ordered_academic_reports_by_date AS ( |
| 96 | SELECT |
| 97 | ar.academic_field, |
| 98 | r.created_at, |
| 99 | ROW_NUMBER() OVER (PARTITION BY ar.academic_field ORDER BY r.created_at) AS row_num |
| 100 | FROM report r |
| 101 | JOIN academicreport ar ON ar.report_id = r.report_id |
| 102 | WHERE r.person_id = :person_id |
| 103 | ), |
| 104 | |
| 105 | filtered_academic_pathway AS ( |
| 106 | SELECT academic_field, MIN(created_at) AS started_on |
| 107 | FROM ordered_academic_reports_by_date |
| 108 | GROUP BY academic_field |
| 109 | ), |
| 110 | |
| 111 | employment_report_stats AS ( |
| 112 | SELECT |
| 113 | CAST(SUM(ABS(COALESCE(e.end_date, CURRENT_DATE) - e.start_date)) AS BIGINT) AS total_working_in_days, |
| 114 | CAST(CEIL(SUM(ABS(COALESCE(e.end_date, CURRENT_DATE) - e.start_date)) / 30.0) AS BIGINT) AS total_working_in_months, |
| 115 | CAST(CEIL(SUM(ABS(COALESCE(e.end_date, CURRENT_DATE) - e.start_date)) / 365.0) AS BIGINT) AS total_working_in_years, |
| 116 | CAST(MAX(COALESCE(e.end_date, CURRENT_DATE) - e.start_date) AS BIGINT) AS longest_job_days |
| 117 | FROM employmentreport e |
| 118 | JOIN report r ON r.report_id = e.report_id |
| 119 | WHERE r.person_id = :person_id |
| 120 | ) |
| 121 | SELECT |
| 122 | -- General |
| 123 | CAST((SELECT COUNT(*) FROM selected_person_reports) AS BIGINT) AS total_reports_found, |
| 124 | CAST((SELECT created_at::date FROM selected_person_reports ORDER BY created_at ASC LIMIT 1) AS DATE) AS first_report_of_person, |
| 125 | CAST((SELECT created_at::date FROM selected_person_reports ORDER BY created_at DESC LIMIT 1) AS DATE) AS latest_report_of_person, |
| 126 | -- Academic |
| 127 | CAST((SELECT COUNT(*) FROM academic) AS BIGINT) AS academic_total, |
| 128 | CAST((SELECT academic_field |
| 129 | FROM academic |
| 130 | GROUP BY academic_field |
| 131 | ORDER BY COUNT(*) DESC |
| 132 | LIMIT 1) AS TEXT) AS most_common_field, |
| 133 | CAST((SELECT STRING_AGG(academic_field, ' → ' ORDER BY started_on) |
| 134 | FROM filtered_academic_pathway) AS TEXT) AS education_path, |
| 135 | -- Employment |
| 136 | CAST((SELECT COUNT(*) FROM employment) AS BIGINT) AS job_count, |
| 137 | (SELECT total_working_in_days FROM employment_report_stats), |
| 138 | (SELECT total_working_in_months FROM employment_report_stats), |
| 139 | (SELECT total_working_in_years FROM employment_report_stats), |
| 140 | (SELECT longest_job_days FROM employment_report_stats), |
| 141 | CAST((SELECT MAX(income_per_month) FROM employment) AS DOUBLE PRECISION) AS max_income_from_job, |
| 142 | -- Medical |
| 143 | CAST((SELECT COUNT(*) FROM medical) AS BIGINT) AS diagnosis_total, |
| 144 | CAST((SELECT ROUND(SUM(CASE WHEN is_chronic THEN 1 ELSE 0 END)::decimal / COUNT(*), 2) |
| 145 | FROM medical) AS DOUBLE PRECISION) AS chronic_ratio, |
| 146 | CAST((SELECT short_description |
| 147 | FROM medical |
| 148 | GROUP BY short_description |
| 149 | ORDER BY COUNT(*) DESC |
| 150 | LIMIT 1) AS TEXT) AS most_frequent_diagnosis, |
| 151 | -- Criminal |
| 152 | CAST((SELECT COUNT(*) FROM criminal) AS BIGINT) AS criminal_case_total, |
| 153 | CAST((SELECT ROUND(SUM(CASE WHEN is_resolved THEN 1 ELSE 0 END)::decimal / COUNT(*), 2) |
| 154 | FROM criminal) AS DOUBLE PRECISION) AS resolution_ratio |
| 155 | }}} |