1+ CREATE TABLE employee (
2+ emp_no SERIAL NOT NULL ,
3+ birth_date DATE NOT NULL ,
4+ first_name TEXT NOT NULL ,
5+ last_name TEXT NOT NULL ,
6+ gender TEXT NOT NULL CHECK (gender IN (' M' , ' F' )) NOT NULL ,
7+ hire_date DATE NOT NULL ,
8+ PRIMARY KEY (emp_no)
9+ );
10+
11+ CREATE INDEX idx_employee_hire_date ON employee (hire_date);
12+
13+ CREATE TABLE department (
14+ dept_no TEXT NOT NULL ,
15+ dept_name TEXT NOT NULL ,
16+ PRIMARY KEY (dept_no),
17+ UNIQUE (dept_name)
18+ );
19+
20+ CREATE TABLE dept_manager (
21+ emp_no INT NOT NULL ,
22+ dept_no TEXT NOT NULL ,
23+ from_date DATE NOT NULL ,
24+ to_date DATE NOT NULL ,
25+ FOREIGN KEY (emp_no) REFERENCES employee (emp_no) ON DELETE CASCADE ,
26+ FOREIGN KEY (dept_no) REFERENCES department (dept_no) ON DELETE CASCADE ,
27+ PRIMARY KEY (emp_no, dept_no)
28+ );
29+
30+ CREATE TABLE dept_emp (
31+ emp_no INT NOT NULL ,
32+ dept_no TEXT NOT NULL ,
33+ from_date DATE NOT NULL ,
34+ to_date DATE NOT NULL ,
35+ FOREIGN KEY (emp_no) REFERENCES employee (emp_no) ON DELETE CASCADE ,
36+ FOREIGN KEY (dept_no) REFERENCES department (dept_no) ON DELETE CASCADE ,
37+ PRIMARY KEY (emp_no, dept_no)
38+ );
39+
40+ CREATE TABLE title (
41+ emp_no INT NOT NULL ,
42+ title TEXT NOT NULL ,
43+ from_date DATE NOT NULL ,
44+ to_date DATE ,
45+ FOREIGN KEY (emp_no) REFERENCES employee (emp_no) ON DELETE CASCADE ,
46+ PRIMARY KEY (emp_no, title, from_date)
47+ );
48+
49+ CREATE TABLE salary (
50+ emp_no INT NOT NULL ,
51+ amount INT NOT NULL ,
52+ from_date DATE NOT NULL ,
53+ to_date DATE NOT NULL ,
54+ FOREIGN KEY (emp_no) REFERENCES employee (emp_no) ON DELETE CASCADE ,
55+ PRIMARY KEY (emp_no, from_date)
56+ );
57+
58+ CREATE INDEX idx_salary_amount ON salary (amount);
59+
60+ CREATE TABLE audit (
61+ id SERIAL PRIMARY KEY ,
62+ operation TEXT NOT NULL ,
63+ query TEXT ,
64+ user_name TEXT NOT NULL ,
65+ changed_at TIMESTAMPTZ DEFAULT CURRENT_TIMESTAMP
66+ );
67+
68+ CREATE INDEX idx_audit_operation ON audit (operation);
69+ CREATE INDEX idx_audit_username ON audit (user_name);
70+ CREATE INDEX idx_audit_changed_at ON audit (changed_at);
71+
72+ CREATE OR REPLACE FUNCTION log_dml_operations () RETURNS TRIGGER AS $$
73+ BEGIN
74+ IF (TG_OP = ' INSERT' ) THEN
75+ INSERT INTO audit (operation, query, user_name)
76+ VALUES (' INSERT' , current_query(), current_user );
77+ RETURN NEW;
78+ ELSIF (TG_OP = ' UPDATE' ) THEN
79+ INSERT INTO audit (operation, query, user_name)
80+ VALUES (' UPDATE' , current_query(), current_user );
81+ RETURN NEW;
82+ ELSIF (TG_OP = ' DELETE' ) THEN
83+ INSERT INTO audit (operation, query, user_name)
84+ VALUES (' DELETE' , current_query(), current_user );
85+ RETURN OLD;
86+ END IF;
87+ RETURN NULL ;
88+ END;
89+ $$ LANGUAGE plpgsql;
90+
91+ -- only log update and delete, otherwise, it will cause too much change.
92+ CREATE TRIGGER salary_log_trigger
93+ AFTER UPDATE OR DELETE ON salary
94+ FOR EACH ROW
95+ EXECUTE FUNCTION log_dml_operations();
96+
97+ CREATE OR REPLACE VIEW dept_emp_latest_date AS
98+ SELECT
99+ emp_no,
100+ MAX (
101+ from_date) AS from_date,
102+ MAX (
103+ to_date) AS to_date
104+ FROM
105+ dept_emp
106+ GROUP BY
107+ emp_no;
108+
109+ -- shows only the current department for each employee
110+ CREATE OR REPLACE VIEW current_dept_emp AS
111+ SELECT
112+ l .emp_no ,
113+ dept_no,
114+ l .from_date ,
115+ l .to_date
116+ FROM
117+ dept_emp d
118+ INNER JOIN dept_emp_latest_date l ON d .emp_no = l .emp_no
119+ AND d .from_date = l .from_date
120+ AND l .to_date = d .to_date ;
0 commit comments