Поправил id дисциплины
This commit is contained in:
295
db/init/init.sql
295
db/init/init.sql
@@ -1,10 +1,18 @@
|
||||
-- ==========================================
|
||||
-- Инициализация расширений
|
||||
-- ==========================================
|
||||
CREATE EXTENSION IF NOT EXISTS pgcrypto;
|
||||
|
||||
-- ==========================================
|
||||
-- Пользователи и роли
|
||||
-- ==========================================
|
||||
CREATE TABLE IF NOT EXISTS users (
|
||||
id BIGSERIAL PRIMARY KEY,
|
||||
username VARCHAR(50) UNIQUE NOT NULL,
|
||||
password VARCHAR(255) NOT NULL,
|
||||
role VARCHAR(20) NOT NULL DEFAULT 'STUDENT'
|
||||
role VARCHAR(20) NOT NULL DEFAULT 'STUDENT',
|
||||
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||||
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
|
||||
);
|
||||
|
||||
-- Админ по умолчанию: admin / admin (bcrypt через pgcrypto)
|
||||
@@ -12,19 +20,49 @@ INSERT INTO users (username, password, role)
|
||||
VALUES ('admin', crypt('admin', gen_salt('bf', 10)), 'ADMIN')
|
||||
ON CONFLICT (username) DO NOTHING;
|
||||
|
||||
-- ==========================================
|
||||
-- Образовательные формы
|
||||
-- ==========================================
|
||||
CREATE TABLE IF NOT EXISTS education_forms (
|
||||
id BIGSERIAL PRIMARY KEY,
|
||||
name VARCHAR(100) UNIQUE NOT NULL
|
||||
name VARCHAR(100) UNIQUE NOT NULL,
|
||||
description TEXT,
|
||||
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
|
||||
);
|
||||
|
||||
INSERT INTO education_forms (name) VALUES ('Бакалавриат'), ('Магистратура'), ('Специалитет')
|
||||
INSERT INTO education_forms (name) VALUES
|
||||
('Бакалавриат'),
|
||||
('Магистратура'),
|
||||
('Специалитет')
|
||||
ON CONFLICT (name) DO NOTHING;
|
||||
|
||||
-- ==========================================
|
||||
-- Учебные группы
|
||||
-- ==========================================
|
||||
CREATE TABLE IF NOT EXISTS student_groups (
|
||||
id BIGSERIAL PRIMARY KEY,
|
||||
name VARCHAR(100) UNIQUE NOT NULL,
|
||||
education_form_id BIGINT NOT NULL REFERENCES education_forms(id)
|
||||
education_form_id BIGINT NOT NULL REFERENCES education_forms(id),
|
||||
course INT CHECK (course BETWEEN 1 AND 6),
|
||||
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
|
||||
);
|
||||
|
||||
-- Тестовая базовая группа для работы
|
||||
INSERT INTO student_groups (name, education_form_id, course)
|
||||
VALUES ('ИВТ-21-1', 1, 3)
|
||||
ON CONFLICT (name) DO NOTHING;
|
||||
|
||||
-- ==========================================
|
||||
-- Подгруппы (например: "ИВТ-21-1 Подгруппа 1")
|
||||
-- ==========================================
|
||||
CREATE TABLE IF NOT EXISTS subgroups (
|
||||
id BIGSERIAL PRIMARY KEY,
|
||||
group_id BIGINT NOT NULL REFERENCES student_groups(id) ON DELETE CASCADE,
|
||||
name VARCHAR(100) NOT NULL,
|
||||
student_capacity INT,
|
||||
UNIQUE(group_id, name)
|
||||
);
|
||||
|
||||
-- ==========================================
|
||||
-- Справочники
|
||||
-- ==========================================
|
||||
@@ -32,96 +70,114 @@ CREATE TABLE IF NOT EXISTS student_groups (
|
||||
-- Дисциплины
|
||||
CREATE TABLE IF NOT EXISTS subjects (
|
||||
id BIGSERIAL PRIMARY KEY,
|
||||
name VARCHAR(200) UNIQUE NOT NULL
|
||||
name VARCHAR(200) UNIQUE NOT NULL,
|
||||
code VARCHAR(20),
|
||||
description TEXT,
|
||||
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
|
||||
);
|
||||
|
||||
INSERT INTO subjects (name) VALUES
|
||||
('Высшая математика'),
|
||||
('Философия'),
|
||||
('Информатика'),
|
||||
('Базы данных'),
|
||||
('Английский язык')
|
||||
('Высшая математика'),
|
||||
('Философия'),
|
||||
('Информатика'),
|
||||
('Базы данных'),
|
||||
('Английский язык')
|
||||
ON CONFLICT (name) DO NOTHING;
|
||||
|
||||
-- Типы занятий
|
||||
CREATE TABLE IF NOT EXISTS lesson_types (
|
||||
id BIGSERIAL PRIMARY KEY,
|
||||
name VARCHAR(50) UNIQUE NOT NULL
|
||||
name VARCHAR(50) UNIQUE NOT NULL,
|
||||
color_code VARCHAR(7) DEFAULT '#3788d8', -- для цветовой индикации в календаре
|
||||
duration_minutes INT DEFAULT 90
|
||||
);
|
||||
|
||||
INSERT INTO lesson_types (name) VALUES
|
||||
('Лекция'),
|
||||
('Практика'),
|
||||
('Лабораторная работа')
|
||||
INSERT INTO lesson_types (name, color_code) VALUES
|
||||
('Лекция', '#FF6B6B'),
|
||||
('Практика', '#4ECDC4'),
|
||||
('Лабораторная работа', '#45B7D1')
|
||||
ON CONFLICT (name) DO NOTHING;
|
||||
|
||||
-- Оборудование
|
||||
CREATE TABLE IF NOT EXISTS equipments (
|
||||
id BIGSERIAL PRIMARY KEY,
|
||||
name VARCHAR(50) UNIQUE NOT NULL
|
||||
name VARCHAR(50) UNIQUE NOT NULL,
|
||||
description TEXT,
|
||||
inventory_number VARCHAR(50)
|
||||
);
|
||||
|
||||
INSERT INTO equipments (name) VALUES
|
||||
('Проектор'),
|
||||
('ПК'),
|
||||
('Лаборатория'),
|
||||
('Интерактивная доска')
|
||||
('Проектор'),
|
||||
('ПК'),
|
||||
('Лаборатория'),
|
||||
('Интерактивная доска'),
|
||||
('Документ-камера'),
|
||||
('Аудиосистема')
|
||||
ON CONFLICT (name) DO NOTHING;
|
||||
|
||||
-- Аудитории
|
||||
CREATE TABLE IF NOT EXISTS classrooms (
|
||||
id BIGSERIAL PRIMARY KEY,
|
||||
name VARCHAR(50) UNIQUE NOT NULL,
|
||||
capacity INT NOT NULL,
|
||||
is_available BOOLEAN DEFAULT TRUE
|
||||
capacity INT NOT NULL CHECK (capacity > 0),
|
||||
building VARCHAR(50),
|
||||
floor INT,
|
||||
is_available BOOLEAN DEFAULT TRUE,
|
||||
description TEXT,
|
||||
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
|
||||
);
|
||||
|
||||
INSERT INTO classrooms (name, capacity) VALUES
|
||||
('101 Ленинская', 120),
|
||||
('202 IT Lab', 20),
|
||||
('303 Обычная', 30)
|
||||
INSERT INTO classrooms (name, capacity, building, floor) VALUES
|
||||
('101 Ленинская', 120, 'Главный корпус', 1),
|
||||
('202 IT Lab', 20, 'Корпус IT', 2),
|
||||
('303 Обычная', 30, 'Главный корпус', 3)
|
||||
ON CONFLICT (name) DO NOTHING;
|
||||
|
||||
-- Привязка оборудования к аудиториям (Many-to-Many)
|
||||
CREATE TABLE IF NOT EXISTS classroom_equipments (
|
||||
classroom_id BIGINT NOT NULL REFERENCES classrooms(id) ON DELETE CASCADE,
|
||||
equipment_id BIGINT NOT NULL REFERENCES equipments(id) ON DELETE CASCADE,
|
||||
quantity INT DEFAULT 1 CHECK (quantity > 0),
|
||||
notes TEXT,
|
||||
PRIMARY KEY (classroom_id, equipment_id)
|
||||
);
|
||||
|
||||
-- Заполнение привязок оборудования (на основе ID базовых данных)
|
||||
-- '101 Ленинская' -> Проектор (1), Интерактивная доска (4)
|
||||
INSERT INTO classroom_equipments (classroom_id, equipment_id) VALUES
|
||||
(1, 1), (1, 4),
|
||||
-- '202 IT Lab' -> ПК (2), Проектор (1), Лаборатория (3)
|
||||
(2, 2), (2, 1), (2, 3)
|
||||
-- '303 Обычная' -> ничего
|
||||
ON CONFLICT DO NOTHING;
|
||||
-- Заполнение привязок оборудования с использованием подзапросов
|
||||
INSERT INTO classroom_equipments (classroom_id, equipment_id, quantity)
|
||||
SELECT c.id, e.id,
|
||||
CASE
|
||||
WHEN e.name = 'ПК' AND c.name = '202 IT Lab' THEN 15
|
||||
WHEN e.name = 'ПК' THEN 1
|
||||
ELSE 1
|
||||
END
|
||||
FROM classrooms c, equipments e
|
||||
WHERE
|
||||
(c.name = '101 Ленинская' AND e.name IN ('Проектор', 'Интерактивная доска', 'Аудиосистема'))
|
||||
OR (c.name = '202 IT Lab' AND e.name IN ('ПК', 'Проектор', 'Лаборатория', 'Интерактивная доска'))
|
||||
OR (c.name = '303 Обычная' AND e.name IN ('Проектор'))
|
||||
ON CONFLICT (classroom_id, equipment_id) DO NOTHING;
|
||||
|
||||
-- ==========================================
|
||||
-- Связи для преподавателей и студентов
|
||||
-- Связи для преподавателей
|
||||
-- ==========================================
|
||||
|
||||
-- Подгруппы (например: "ИВТ-21-1 Подгруппа 1")
|
||||
CREATE TABLE IF NOT EXISTS subgroups (
|
||||
id BIGSERIAL PRIMARY KEY,
|
||||
group_id BIGINT NOT NULL REFERENCES student_groups(id) ON DELETE CASCADE,
|
||||
name VARCHAR(100) NOT NULL,
|
||||
UNIQUE(group_id, name)
|
||||
);
|
||||
|
||||
-- Тестовая базовая группа для работы
|
||||
INSERT INTO student_groups (name, education_form_id)
|
||||
VALUES ('ИВТ-21-1', 1)
|
||||
ON CONFLICT (name) DO NOTHING;
|
||||
|
||||
-- Привязка преподавателей к дисциплинам
|
||||
CREATE TABLE IF NOT EXISTS teacher_subjects (
|
||||
user_id BIGINT NOT NULL REFERENCES users(id) ON DELETE CASCADE,
|
||||
subject_id BIGINT NOT NULL REFERENCES subjects(id) ON DELETE CASCADE,
|
||||
qualification_level VARCHAR(50),
|
||||
experience_years INT,
|
||||
PRIMARY KEY(user_id, subject_id)
|
||||
);
|
||||
|
||||
-- Какие типы занятий может вести преподаватель по дисциплине
|
||||
CREATE TABLE IF NOT EXISTS teacher_lesson_types (
|
||||
user_id BIGINT NOT NULL REFERENCES users(id) ON DELETE CASCADE,
|
||||
subject_id BIGINT NOT NULL REFERENCES subjects(id) ON DELETE CASCADE,
|
||||
lesson_type_id BIGINT NOT NULL REFERENCES lesson_types(id) ON DELETE CASCADE,
|
||||
PRIMARY KEY (user_id, subject_id, lesson_type_id)
|
||||
);
|
||||
|
||||
-- ==========================================
|
||||
-- Основная таблица Расписания (Lessons)
|
||||
-- ==========================================
|
||||
@@ -131,11 +187,142 @@ CREATE TABLE IF NOT EXISTS lessons (
|
||||
subject_id BIGINT NOT NULL REFERENCES subjects(id),
|
||||
lesson_type_id BIGINT NOT NULL REFERENCES lesson_types(id),
|
||||
classroom_id BIGINT NOT NULL REFERENCES classrooms(id),
|
||||
group_id BIGINT NOT NULL REFERENCES student_groups(id), -- первичная группа
|
||||
subgroup_id BIGINT REFERENCES subgroups(id), -- необязательно (если делим группу)
|
||||
group_id BIGINT NOT NULL REFERENCES student_groups(id),
|
||||
subgroup_id BIGINT REFERENCES subgroups(id),
|
||||
|
||||
day_of_week INT NOT NULL CHECK (day_of_week BETWEEN 1 AND 7), -- 1=Понедельник, 7=Воскресенье
|
||||
is_even_week BOOLEAN NOT NULL, -- Четная/нечетная неделя
|
||||
start_time TIME NOT NULL, -- Напр. '08:00:00'
|
||||
end_time TIME NOT NULL -- Напр. '09:30:00'
|
||||
day_of_week INT NOT NULL CHECK (day_of_week BETWEEN 1 AND 7),
|
||||
is_even_week BOOLEAN NOT NULL,
|
||||
start_time TIME NOT NULL,
|
||||
end_time TIME NOT NULL,
|
||||
|
||||
-- Дополнительные поля
|
||||
semester INT CHECK (semester BETWEEN 1 AND 12),
|
||||
academic_year VARCHAR(9), -- например: '2023-2024'
|
||||
is_active BOOLEAN DEFAULT TRUE,
|
||||
notes TEXT,
|
||||
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||||
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||||
|
||||
-- Проверки
|
||||
CHECK (end_time > start_time),
|
||||
CHECK (end_time <= start_time + INTERVAL '4 hours') -- Максимальная длина занятия 4 часа
|
||||
);
|
||||
|
||||
-- Индексы для эффективного поиска
|
||||
CREATE INDEX IF NOT EXISTS idx_lessons_teacher ON lessons(teacher_id, day_of_week, is_even_week);
|
||||
CREATE INDEX IF NOT EXISTS idx_lessons_group ON lessons(group_id, day_of_week, is_even_week);
|
||||
CREATE INDEX IF NOT EXISTS idx_lessons_classroom ON lessons(classroom_id, day_of_week, is_even_week, start_time);
|
||||
CREATE INDEX IF NOT EXISTS idx_lessons_datetime ON lessons(day_of_week, start_time, end_time);
|
||||
CREATE INDEX IF NOT EXISTS idx_lessons_active ON lessons(is_active);
|
||||
|
||||
-- ==========================================
|
||||
-- Таблица для отслеживания замен и изменений в расписании
|
||||
-- ==========================================
|
||||
CREATE TABLE IF NOT EXISTS schedule_changes (
|
||||
id BIGSERIAL PRIMARY KEY,
|
||||
original_lesson_id BIGINT REFERENCES lessons(id) ON DELETE SET NULL,
|
||||
new_teacher_id BIGINT REFERENCES users(id),
|
||||
new_classroom_id BIGINT REFERENCES classrooms(id),
|
||||
new_start_time TIME,
|
||||
new_end_time TIME,
|
||||
change_reason TEXT NOT NULL,
|
||||
changed_by BIGINT REFERENCES users(id),
|
||||
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||||
effective_date DATE NOT NULL
|
||||
);
|
||||
|
||||
-- ==========================================
|
||||
-- Функция для проверки пересечений расписания
|
||||
-- ==========================================
|
||||
CREATE OR REPLACE FUNCTION check_schedule_conflict()
|
||||
RETURNS TRIGGER AS $$
|
||||
BEGIN
|
||||
-- Проверка пересечений для преподавателя
|
||||
IF EXISTS (
|
||||
SELECT 1 FROM lessons
|
||||
WHERE teacher_id = NEW.teacher_id
|
||||
AND day_of_week = NEW.day_of_week
|
||||
AND is_even_week = NEW.is_even_week
|
||||
AND id != COALESCE(NEW.id, -1)
|
||||
AND (
|
||||
(start_time <= NEW.start_time AND end_time > NEW.start_time)
|
||||
OR (start_time < NEW.end_time AND end_time >= NEW.end_time)
|
||||
OR (start_time >= NEW.start_time AND end_time <= NEW.end_time)
|
||||
)
|
||||
) THEN
|
||||
RAISE EXCEPTION 'Конфликт расписания для преподавателя';
|
||||
END IF;
|
||||
|
||||
-- Проверка пересечений для аудитории
|
||||
IF EXISTS (
|
||||
SELECT 1 FROM lessons
|
||||
WHERE classroom_id = NEW.classroom_id
|
||||
AND day_of_week = NEW.day_of_week
|
||||
AND is_even_week = NEW.is_even_week
|
||||
AND id != COALESCE(NEW.id, -1)
|
||||
AND (
|
||||
(start_time <= NEW.start_time AND end_time > NEW.start_time)
|
||||
OR (start_time < NEW.end_time AND end_time >= NEW.end_time)
|
||||
OR (start_time >= NEW.start_time AND end_time <= NEW.end_time)
|
||||
)
|
||||
) THEN
|
||||
RAISE EXCEPTION 'Конфликт расписания для аудитории';
|
||||
END IF;
|
||||
|
||||
-- Проверка пересечений для группы
|
||||
IF EXISTS (
|
||||
SELECT 1 FROM lessons
|
||||
WHERE group_id = NEW.group_id
|
||||
AND day_of_week = NEW.day_of_week
|
||||
AND is_even_week = NEW.is_even_week
|
||||
AND id != COALESCE(NEW.id, -1)
|
||||
AND (
|
||||
(start_time <= NEW.start_time AND end_time > NEW.start_time)
|
||||
OR (start_time < NEW.end_time AND end_time >= NEW.end_time)
|
||||
OR (start_time >= NEW.start_time AND end_time <= NEW.end_time)
|
||||
)
|
||||
) THEN
|
||||
RAISE EXCEPTION 'Конфликт расписания для группы';
|
||||
END IF;
|
||||
|
||||
RETURN NEW;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
-- Триггер для проверки конфликтов при вставке/обновлении
|
||||
DROP TRIGGER IF EXISTS check_lesson_conflict ON lessons;
|
||||
CREATE TRIGGER check_lesson_conflict
|
||||
BEFORE INSERT OR UPDATE ON lessons
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION check_schedule_conflict();
|
||||
|
||||
-- ==========================================
|
||||
-- Функция обновления timestamp
|
||||
-- ==========================================
|
||||
CREATE OR REPLACE FUNCTION update_updated_at_column()
|
||||
RETURNS TRIGGER AS $$
|
||||
BEGIN
|
||||
NEW.updated_at = CURRENT_TIMESTAMP;
|
||||
RETURN NEW;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
-- Триггеры для обновления updated_at
|
||||
CREATE TRIGGER update_users_updated_at
|
||||
BEFORE UPDATE ON users
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION update_updated_at_column();
|
||||
|
||||
CREATE TRIGGER update_lessons_updated_at
|
||||
BEFORE UPDATE ON lessons
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION update_updated_at_column();
|
||||
|
||||
-- ==========================================
|
||||
-- Комментарии к таблицам и полям (для документации)
|
||||
-- ==========================================
|
||||
COMMENT ON TABLE users IS 'Пользователи системы (студенты, преподаватели, администраторы)';
|
||||
COMMENT ON TABLE lessons IS 'Основное расписание занятий';
|
||||
COMMENT ON COLUMN lessons.day_of_week IS 'День недели (1-Пн, 2-Вт, 3-Ср, 4-Чт, 5-Пт, 6-Сб, 7-Вс)';
|
||||
COMMENT ON COLUMN lessons.is_even_week IS 'true - четная неделя, false - нечетная';
|
||||
COMMENT ON TABLE schedule_changes IS 'История изменений и замен в расписании';
|
||||
Reference in New Issue
Block a user