127 lines
5.1 KiB
SQL
127 lines
5.1 KiB
SQL
-- #
|
||
-- # "contingent-movement" project;
|
||
-- # author: gazakbayev.net
|
||
-- # ver: 1.0
|
||
-- #
|
||
|
||
CREATE TABLE Physicals (
|
||
passport_no VARCHAR(30) PRIMARY KEY,
|
||
name VARCHAR(255) NOT NULL,
|
||
surname VARCHAR(255) NOT NULL,
|
||
birthday TIMESTAMP NOT NULL,
|
||
phone VARCHAR(20) NOT NULL,
|
||
mail VARCHAR(255) NOT NULL,
|
||
citizenship VARCHAR(50) NOT NULL,
|
||
address VARCHAR(255) NOT NULL,
|
||
access_card VARCHAR(20) NOT NULL CHECK (access_card ~ '^[A-F0-9]{2}(:[A-F0-9]{2}){5}$'),
|
||
access_level VARCHAR(10) NOT NULL CHECK (access_level IN ('КАМПУС', 'ОБЩЕЖИТИЯ', 'ПОЛНЫЙ'))
|
||
);
|
||
|
||
CREATE TABLE Supervisors (
|
||
id SERIAL PRIMARY KEY,
|
||
person VARCHAR(32) REFERENCES Physicals(passport_no),
|
||
experience INTEGER NOT NULL CHECK (experience >= 0),
|
||
defended_ratio REAL NOT NULL CHECK (defended_ratio >= 0 AND defended_ratio <= 1),
|
||
qualification VARCHAR(30) NOT NULL CHECK (qualification IN ('МЛАДШИЙ НАУЧНЫЙ СОТРУДНИК', 'СТАРШИЙ НАУЧНЫЙ СОТРУДНИК', 'ВЕДУЩИЙ НАУЧНЫЙ СОТРУДНИК', 'ГЛАВНЫЙ НАУЧНЫЙ СОТРУДНИК', 'НАУЧНЫЙ СОТРУДНИК')),
|
||
valid_from TIMESTAMP NOT NULL,
|
||
valid_to TIMESTAMP
|
||
);
|
||
|
||
CREATE TABLE Faculties (
|
||
id SERIAL PRIMARY KEY,
|
||
name VARCHAR(255) NOT NULL,
|
||
acronym VARCHAR(10) NOT NULL,
|
||
head VARCHAR(32) NOT NULL REFERENCES Physicals(passport_no),
|
||
vice VARCHAR(32) REFERENCES Physicals(passport_no),
|
||
address VARCHAR(255) NOT NULL
|
||
);
|
||
|
||
CREATE TABLE Departments (
|
||
id SERIAL PRIMARY KEY,
|
||
name VARCHAR(255) NOT NULL,
|
||
acronym VARCHAR(10) NOT NULL,
|
||
founded TIMESTAMP NOT NULL,
|
||
head VARCHAR(32) NOT NULL REFERENCES Physicals(passport_no),
|
||
vice VARCHAR(32) REFERENCES Physicals(passport_no),
|
||
secretary VARCHAR(32) REFERENCES Physicals(passport_no),
|
||
faculty_id INTEGER REFERENCES Faculties(id)
|
||
);
|
||
|
||
CREATE TABLE Programs (
|
||
id SERIAL PRIMARY KEY,
|
||
specification VARCHAR(20) NOT NULL,
|
||
degree VARCHAR(30) NOT NULL CHECK (degree IN ('BACHELOR', 'MAGISTER', 'ASPIRANT')),
|
||
name VARCHAR(255) NOT NULL,
|
||
parent_id INTEGER REFERENCES Programs(id)
|
||
);
|
||
|
||
CREATE TABLE Groups (
|
||
group_id VARCHAR(10) PRIMARY KEY CHECK (group_id ~ '^[АБМ]\d{2}-\d{3}[а-я]?$'),
|
||
faculty_id INTEGER NOT NULL REFERENCES Faculties(id),
|
||
program_id INTEGER NOT NULL REFERENCES Programs(id),
|
||
department_id INTEGER REFERENCES Departments(id),
|
||
study_starts TIMESTAMP NOT NULL DEFAULT NOW(),
|
||
study_ends TIMESTAMP NOT NULL DEFAULT NOW() + INTERVAL '4 years'
|
||
);
|
||
|
||
CREATE TABLE Students (
|
||
id SERIAL PRIMARY KEY,
|
||
person VARCHAR(32) NOT NULL UNIQUE REFERENCES Physicals(passport_no),
|
||
group_id VARCHAR(10) NOT NULL REFERENCES Groups(group_id),
|
||
supervisor_id INTEGER REFERENCES Supervisors(id),
|
||
education_form VARCHAR(255) NOT NULL CHECK (education_form IN ('ОЧНАЯ', 'ЗАОЧНАЯ', 'ВЕЧЕРНЯЯ')),
|
||
status VARCHAR(30) NOT NULL CHECK (status IN ('УЧИТСЯ', 'В АКАДЕМИЧЕСКОМ ОТПУСКЕ', 'ОТЧИСЛЕН'))
|
||
);
|
||
|
||
CREATE TABLE Family (
|
||
id SERIAL PRIMARY KEY,
|
||
person VARCHAR(32) NOT NULL REFERENCES Physicals(passport_no),
|
||
name VARCHAR(255) NOT NULL,
|
||
surname VARCHAR(255) NOT NULL,
|
||
kinship VARCHAR(10) NOT NULL CHECK (kinship IN ('MOTHER', 'FATHER', 'BROTHER', 'SISTER', 'ANOTHER')),
|
||
phone VARCHAR(20) NOT NULL UNIQUE,
|
||
address VARCHAR(255) NOT NULL,
|
||
CONSTRAINT unique_student_kinship UNIQUE (person, kinship)
|
||
);
|
||
|
||
CREATE TABLE Files (
|
||
id SERIAL PRIMARY KEY,
|
||
student_id INTEGER NOT NULL REFERENCES Students(id),
|
||
name VARCHAR(255) NOT NULL,
|
||
description VARCHAR(255) NOT NULL,
|
||
extension VARCHAR(5) NOT NULL CHECK (extension IN ('PNG', 'JPEG', 'PDF')),
|
||
size NUMERIC(10,2) NOT NULL CHECK (size <= 20),
|
||
path VARCHAR(255) NOT NULL UNIQUE,
|
||
loaded_at TIMESTAMP NOT NULL DEFAULT NOW()
|
||
);
|
||
|
||
CREATE TABLE Disciplines (
|
||
id SERIAL PRIMARY KEY,
|
||
name VARCHAR(255) NOT NULL,
|
||
department_id INTEGER NOT NULL REFERENCES Departments(id),
|
||
credit_units INTEGER NOT NULL,
|
||
academic_hours INTEGER NOT NULL,
|
||
general_hours INTEGER NOT NULL CHECK (general_hours > academic_hours),
|
||
is_annual BOOLEAN NOT NULL
|
||
);
|
||
|
||
CREATE TABLE Statements (
|
||
id SERIAL PRIMARY KEY,
|
||
student_id INTEGER NOT NULL REFERENCES Students(id),
|
||
discipline_id INTEGER NOT NULL REFERENCES Disciplines(id),
|
||
examiner VARCHAR(32) NOT NULL REFERENCES Physicals(passport_no),
|
||
try_no INTEGER NOT NULL CHECK (try_no BETWEEN 0 AND 2),
|
||
grade INTEGER NOT NULL CHECK (grade BETWEEN 1 AND 10),
|
||
conducted_at TIMESTAMP NOT NULL DEFAULT NOW()
|
||
);
|
||
|
||
CREATE TABLE Movement (
|
||
id SERIAL PRIMARY KEY,
|
||
student_id INTEGER NOT NULL REFERENCES Students(id),
|
||
type VARCHAR(30) NOT NULL CHECK (type IN ('ЗАЧИСЛЕН', 'ВОССТАНОВЛЕН', 'ОТЧИСЛЕН', 'В АКАДЕМИЧЕСКИЙ ОТПУСК', 'ПЕРЕВОД В ДРУГУЮ ГРУППУ')),
|
||
new_group VARCHAR(10) REFERENCES Groups(group_id),
|
||
new_status VARCHAR(30) CHECK (new_status IN ('УЧИТСЯ', 'В АКАДЕМИЧЕСКОМ ОТПУСКЕ', 'ОТЧИСЛЕН')),
|
||
issued_at TIMESTAMP NOT NULL DEFAULT NOW()
|
||
);
|
||
|