Projekt

Obecné

Profil

Stáhnout (7.37 KB) Statistiky
| Větev: | Tag: | Revize:
1
-- -----------------------------------------------------
2
-- Table role
3
-- -----------------------------------------------------
4
DROP TABLE IF EXISTS role;
5
CREATE TABLE role (
6
  id TINYINT NOT NULL AUTO_INCREMENT,
7
  name VARCHAR(8) NOT NULL,
8
  PRIMARY KEY (id)
9
);
10

    
11
-- -----------------------------------------------------
12
-- Table approval_status
13
-- -----------------------------------------------------
14
DROP TABLE IF EXISTS approval_status;
15
CREATE TABLE approval_status (
16
  id TINYINT NOT NULL AUTO_INCREMENT,
17
  name VARCHAR(8) NOT NULL,
18
  PRIMARY KEY (id)
19
);
20

    
21
-- -----------------------------------------------------
22
-- Table vacation_type
23
-- -----------------------------------------------------
24
DROP TABLE IF EXISTS vacation_type;
25
CREATE TABLE vacation_type (
26
  id TINYINT NOT NULL AUTO_INCREMENT,
27
  name VARCHAR(8) NOT NULL,
28
  PRIMARY KEY (id)
29
);
30

    
31
-- -----------------------------------------------------
32
-- Table end_user
33
-- -----------------------------------------------------
34
DROP TABLE IF EXISTS end_user;
35
CREATE TABLE end_user (
36
  id BIGINT NOT NULL AUTO_INCREMENT,
37
  first_name VARCHAR(45) NOT NULL,
38
  last_name VARCHAR(45) NOT NULL,
39
  no_vacations FLOAT,
40
  no_sick_days INT,
41
  taken_vacations FLOAT NOT NULL,
42
  taken_sick_days INT NOT NULL,
43
  alert DATETIME,
44
  token TEXT NOT NULL,
45
  email VARCHAR(100) NOT NULL,
46
  photo TEXT,
47
  creation_date DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP,
48
  role_id TINYINT NOT NULL,
49
  status_id TINYINT NOT NULL,
50
  PRIMARY KEY (id),
51
  INDEX fk_end_user_role (role_id ASC),
52
  INDEX fk_end_user_approval_status (status_id ASC),
53
  CONSTRAINT fk_end_user_role FOREIGN KEY (role_id)
54
    REFERENCES role (id)
55
    ON DELETE CASCADE ON UPDATE CASCADE,
56
  CONSTRAINT fk_end_user_approval_status FOREIGN KEY (status_id)
57
    REFERENCES approval_status (id)
58
    ON DELETE NO ACTION ON UPDATE CASCADE,
59
  CONSTRAINT check_taken_vacation CHECK (taken_vacations >= 0),
60
  CONSTRAINT check_taken_sick_days CHECK (taken_sick_days >= 0)
61
);
62

    
63
-- -----------------------------------------------------
64
-- Table vacation_day
65
-- -----------------------------------------------------
66
DROP TABLE IF EXISTS vacation_day;
67
CREATE TABLE vacation_day (
68
  id BIGINT NOT NULL AUTO_INCREMENT,
69
  vacation_date DATE NOT NULL,
70
  time_from TIME,
71
  time_to TIME,
72
  creation_date DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP,
73
  user_id BIGINT NOT NULL,
74
  status_id TINYINT NOT NULL,
75
  type_id TINYINT NOT NULL,
76
  PRIMARY KEY (id),
77
  INDEX fk_vacation_day_approval_status (status_id ASC),
78
  INDEX fk_vacation_day_end_user (user_id ASC),
79
  INDEX fk_vacation_day_vacation_type (type_id ASC),
80
  CONSTRAINT fk_vacation_day_approval_status FOREIGN KEY (status_id)
81
    REFERENCES approval_status (id)
82
    ON DELETE NO ACTION ON UPDATE CASCADE,
83
  CONSTRAINT fk_vacation_day_end_user FOREIGN KEY (user_id)
84
    REFERENCES end_user (id)
85
    ON DELETE CASCADE ON UPDATE CASCADE,
86
  CONSTRAINT fk_vacation_day_vacation_type FOREIGN KEY (type_id)
87
    REFERENCES vacation_type (id)
88
    ON DELETE CASCADE ON UPDATE CASCADE,
89
  CONSTRAINT check_time CHECK (time_from < time_to)
90
);
91

    
92
-- -----------------------------------------------------
93
-- Table Default_Settings
94
-- -----------------------------------------------------
95
DROP TABLE IF EXISTS default_settings;
96
CREATE TABLE default_settings (
97
  id BIGINT NOT NULL AUTO_INCREMENT,
98
  no_sick_days INT NOT NULL,
99
  alert DATETIME NOT NULL,
100
  creation_date DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP,
101
  PRIMARY KEY (id),
102
  CONSTRAINT check_no_sick_days CHECK (no_sick_days >= 0)
103
);
104

    
105
DELIMITER $$
106
DROP PROCEDURE IF EXISTS GetUserId $$
107
CREATE PROCEDURE GetUserId(
108
  IN in_id BIGINT,
109
  OUT out_id BIGINT,
110
  OUT out_first_name VARCHAR(45),
111
  OUT out_last_name VARCHAR(45),
112
  OUT out_no_vacations FLOAT,
113
  OUT out_no_sick_days INT,
114
  OUT out_taken_vacations FLOAT,
115
  OUT out_taken_sick_days INT,
116
  OUT out_alert DATETIME,
117
  OUT out_email VARCHAR(100),
118
  OUT out_photo TEXT,
119
  OUT out_creation_date DATETIME,
120
  OUT out_role VARCHAR(8),
121
  OUT out_status VARCHAR(8))
122
BEGIN
123
  DECLARE sickDaysCount INT;
124
  DECLARE notification DATETIME;
125

    
126
  SELECT no_sick_days, alert INTO sickDaysCount, notification FROM default_settings ORDER BY id DESC LIMIT 1;
127
  SELECT EU.id, EU.first_name, EU.last_name, EU.no_vacation, IFNULL(EU.no_sick_days, sickDaysCount), EU.taken_vacations, EU.taken_sick_days, IFNULL(EU.alert, notification), EU.email, EU.photo, EU.creation_date, R.name, APS.name
128
     INTO out_id, out_first_name, out_last_name, out_no_vacations, out_no_sick_days, out_taken_vacations, out_taken_sick_days, out_alert, out_email, out_photo, out_creation_date, out_role, out_status
129
     FROM end_user EU
130
     INNER JOIN role R ON EU.role_id=R.id
131
     INNER JOIN approval_status APS ON EU.status_id=APS.id
132
     WHERE EU.id=in_id;
133
END $$
134

    
135
DROP PROCEDURE IF EXISTS GetUserToken $$
136
CREATE PROCEDURE GetUserToken(
137
  IN p_token TEXT,
138
  OUT out_id BIGINT,
139
  OUT out_first_name VARCHAR(45),
140
  OUT out_last_name VARCHAR(45),
141
  OUT out_no_vacations FLOAT,
142
  OUT out_no_sick_days INT,
143
  OUT out_taken_vacations FLOAT,
144
  OUT out_taken_sick_days INT,
145
  OUT out_alert DATETIME,
146
  OUT out_email VARCHAR(100),
147
  OUT out_photo TEXT,
148
  OUT out_creation_date DATETIME,
149
  OUT out_role VARCHAR(8),
150
  OUT out_status VARCHAR(8))
151
BEGIN
152
  DECLARE sickDaysCount INT;
153
  DECLARE notification DATETIME;
154

    
155
  SELECT no_sick_days, alert INTO sickDaysCount, notification FROM default_settings ORDER BY id DESC LIMIT 1;
156
  SELECT EU.id, EU.first_name, EU.last_name, EU.no_vacation, IFNULL(EU.no_sick_days, sickDaysCount), EU.taken_vacations, EU.taken_sick_days, IFNULL(EU.alert, notification), EU.email, EU.photo, EU.creation_date, R.name, APS.name
157
     INTO out_id, out_first_name, out_last_name, out_no_vacations, out_no_sick_days, out_taken_vacations, out_taken_sick_days, out_alert, out_email, out_photo, out_creation_date, out_role, out_status
158
     FROM end_user EU
159
     INNER JOIN role R ON EU.role_id=R.id
160
     INNER JOIN approval_status APS ON EU.status_id=APS.id
161
     WHERE EU.token=p_token;
162
END $$
163

    
164
DELIMITER ;
165

    
166
-- -----------------------------------------------------
167
-- Insert table role
168
-- -----------------------------------------------------
169
INSERT INTO role (name) VALUES ('employee');
170
INSERT INTO role (name) VALUES ('employer');
171

    
172
-- -----------------------------------------------------
173
-- Insert table approval_status
174
-- -----------------------------------------------------
175
INSERT INTO approval_status (name) VALUES ('accepted');
176
INSERT INTO approval_status (name) VALUES ('pending');
177
INSERT INTO approval_status (name) VALUES ('rejected');
178

    
179
-- -----------------------------------------------------
180
-- Insert table vacation_type
181
-- -----------------------------------------------------
182
INSERT INTO vacation_type (name) VALUES ('sickday');
183
INSERT INTO vacation_type (name) VALUES ('vacation');
184

    
185
-- -----------------------------------------------------
186
-- Insert table end_user
187
-- -----------------------------------------------------
188
-- INSERT INTO end_user (first_name, last_name, no_vacations, no_sick_days, alert, token, email, photo, role_id, status_id) VALUES ();
189

    
190
-- -----------------------------------------------------
191
-- Insert table vacation_day
192
-- -----------------------------------------------------
193
-- INSERT INTO vacation_day (vacation_date, time_from, time_to, user_id, status_id, type_id) VALUES ();
194

    
195
-- -----------------------------------------------------
196
-- Insert table default_settings
197
-- -----------------------------------------------------
198
INSERT INTO default_settings (no_sick_days, alert) VALUES (5, '2019-12-01 12:00:00.000');
(4-4/6)