192 lines
5.6 KiB
SQL
192 lines
5.6 KiB
SQL
-- #
|
||
-- # "contingent-movement" project;
|
||
-- # author: gazakbayev.net
|
||
-- # ver: 1.0
|
||
-- #
|
||
|
||
-- 1 Студенты с одинаковыми фамилиями
|
||
|
||
WITH student_info AS (
|
||
SELECT
|
||
s.id as student_id,
|
||
p.passport_no,
|
||
p.surname,
|
||
p.name,
|
||
g.group_id,
|
||
f.name as faculty_name
|
||
FROM Students s
|
||
JOIN Physicals p ON s.person = p.passport_no
|
||
JOIN Groups g ON s.group_id = g.group_id
|
||
JOIN Faculties f ON g.faculty_id = f.id
|
||
)
|
||
SELECT
|
||
a.surname,
|
||
a.name as student1_name,
|
||
b.name as student2_name,
|
||
a.group_id as group1,
|
||
b.group_id as group2,
|
||
a.faculty_name as faculty1,
|
||
b.faculty_name as faculty2
|
||
FROM student_info a
|
||
JOIN student_info b ON a.surname = b.surname
|
||
AND a.student_id < b.student_id
|
||
ORDER BY a.surname, a.name;
|
||
|
||
-- 2 Средний балл студентов
|
||
|
||
SELECT
|
||
s.id AS student_id,
|
||
p.name,
|
||
p.surname,
|
||
ROUND(AVG(st.grade)::numeric, 2) AS average_grade
|
||
FROM
|
||
Students s
|
||
JOIN
|
||
Physicals p ON s.person = p.passport_no
|
||
LEFT JOIN
|
||
Statements st ON s.id = st.student_id
|
||
GROUP BY
|
||
s.id, p.name, p.surname
|
||
ORDER BY
|
||
average_grade DESC NULLS LAST;
|
||
|
||
-- 3 Топ 5 лучших
|
||
|
||
SELECT
|
||
s.id,
|
||
p.surname,
|
||
p.name,
|
||
ROUND(AVG(st.grade)::numeric, 2) AS avg_grade,
|
||
DENSE_RANK() OVER (ORDER BY AVG(st.grade) DESC) AS rank
|
||
FROM Students s
|
||
JOIN Physicals p ON s.person = p.passport_no
|
||
JOIN Statements st ON s.id = st.student_id
|
||
GROUP BY s.id, p.surname, p.name
|
||
ORDER BY avg_grade DESC
|
||
LIMIT 5;
|
||
|
||
-- 4 Количества у кафедры дисциплин и студентов
|
||
|
||
SELECT
|
||
d.name AS department,
|
||
COUNT(DISTINCT disc.id) AS discipline_count,
|
||
COUNT(DISTINCT s.id) AS student_count
|
||
FROM Departments d
|
||
LEFT JOIN Disciplines disc ON d.id = disc.department_id
|
||
LEFT JOIN Groups g ON d.id = g.department_id
|
||
LEFT JOIN Students s ON g.group_id = s.group_id
|
||
GROUP BY d.id
|
||
HAVING COUNT(DISTINCT s.id) > 0
|
||
ORDER BY student_count DESC;
|
||
|
||
-- 5 ФИ обучающихся (статус Учится)
|
||
|
||
SELECT
|
||
p.surname,
|
||
p.name
|
||
FROM Students s
|
||
JOIN Physicals p ON s.person = p.passport_no
|
||
WHERE EXISTS (
|
||
SELECT 1 FROM Statements st
|
||
WHERE st.student_id = s.id
|
||
)
|
||
AND s.status = 'УЧИТСЯ';
|
||
|
||
-- 6 Прогресс изменения среднего балла по студентам
|
||
|
||
SELECT
|
||
s.id,
|
||
p.surname,
|
||
p.name,
|
||
g.group_id,
|
||
st.conducted_at,
|
||
st.grade,
|
||
AVG(st.grade) OVER (PARTITION BY s.id ORDER BY st.conducted_at
|
||
ROWS BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW) AS running_avg
|
||
FROM Students s
|
||
JOIN Physicals p ON s.person = p.passport_no
|
||
JOIN Groups g ON s.group_id = g.group_id
|
||
JOIN Statements st ON s.id = st.student_id
|
||
ORDER BY s.id, st.conducted_at;
|
||
|
||
-- 7 Список группы с обучающимися, с указанием оценки успеваемости студента в группе "Ниже среднего" или "Выше среднего"
|
||
|
||
WITH group_stats AS (
|
||
SELECT
|
||
s.group_id,
|
||
AVG(st.grade) AS group_avg
|
||
FROM Students s
|
||
JOIN Statements st ON s.id = st.student_id
|
||
GROUP BY s.group_id
|
||
)
|
||
SELECT
|
||
s.id,
|
||
p.surname,
|
||
p.name,
|
||
g.group_id,
|
||
ROUND(AVG(st.grade)::numeric, 2) AS student_avg,
|
||
gs.group_avg,
|
||
CASE
|
||
WHEN AVG(st.grade) > gs.group_avg THEN 'Выше среднего'
|
||
WHEN AVG(st.grade) < gs.group_avg THEN 'Ниже среднего'
|
||
ELSE 'Средний'
|
||
END AS comparison
|
||
FROM Students s
|
||
JOIN Physicals p ON s.person = p.passport_no
|
||
JOIN Groups g ON s.group_id = g.group_id
|
||
JOIN Statements st ON s.id = st.student_id
|
||
JOIN group_stats gs ON g.group_id = gs.group_id
|
||
GROUP BY s.id, p.surname, p.name, g.group_id, gs.group_avg
|
||
ORDER BY g.group_id, comparison;
|
||
|
||
-- 8 Статистика отчислений по месяцам, основываясь на движении контингента (приказах)
|
||
SELECT
|
||
DATE_TRUNC('month', m.issued_at) AS month,
|
||
COUNT(*) AS dropouts,
|
||
SUM(COUNT(*)) OVER (ORDER BY DATE_TRUNC('month', m.issued_at)) AS cumulative_total
|
||
FROM Movement m
|
||
WHERE m.type = 'ОТЧИСЛЕН'
|
||
GROUP BY DATE_TRUNC('month', m.issued_at)
|
||
ORDER BY month;
|
||
|
||
-- 9 Научные руководители студентов
|
||
|
||
SELECT
|
||
s.id AS student_id,
|
||
p.name AS student_name,
|
||
p.surname AS student_surname,
|
||
s.supervisor AS supervisor_id,
|
||
ph.name AS supervisor_name,
|
||
ph.surname AS supervisor_surname
|
||
FROM Students s
|
||
JOIN Physicals p ON s.person = p.passport_no
|
||
LEFT JOIN Supervisors sup ON s.supervisor = sup.person
|
||
LEFT JOIN Physicals ph ON sup.person = ph.passport_no
|
||
WHERE s.supervisor IS NOT NULL
|
||
ORDER BY student_surname;
|
||
|
||
-- 10 Вывод преподавателей из ведомости по ФИО, принимающим предметам, средней оценки и уровня халявности:
|
||
|
||
SELECT
|
||
p.surname AS "Фамилия",
|
||
p.name AS "Имя",
|
||
STRING_AGG(DISTINCT d.name, ', ' ORDER BY d.name) AS "Принимает дисциплины",
|
||
ROUND(AVG(st.grade), 2) AS "Средняя оценка",
|
||
CASE
|
||
WHEN AVG(st.grade) < 3 THEN 'Не халявный'
|
||
WHEN AVG(st.grade) < 5 THEN 'Хороший'
|
||
WHEN AVG(st.grade) < 8 THEN 'Халявный'
|
||
ELSE 'Ультра халявный'
|
||
END AS "Уровень халявности"
|
||
FROM
|
||
Statements st
|
||
JOIN
|
||
Physicals p ON st.examiner = p.passport_no
|
||
JOIN
|
||
Disciplines d ON st.discipline_id = d.id
|
||
GROUP BY
|
||
p.passport_no, p.surname, p.name
|
||
HAVING
|
||
COUNT(*) >= 5
|
||
ORDER BY
|
||
"Средняя оценка" DESC; |