-
Notifications
You must be signed in to change notification settings - Fork 50
/
Relational Schema.txt
315 lines (274 loc) · 8.84 KB
/
Relational Schema.txt
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
-- Table structure for table `canc`
CREATE TABLE IF NOT EXISTS `canc` (
`pnr` int(11) NOT NULL,
`rfare` int(11) DEFAULT '0',
PRIMARY KEY (`pnr`)
) ENGINE=InnoDB DEFAULT CHARSET=latin1;
-- Table structure for table `class`
CREATE TABLE IF NOT EXISTS `class` (
`cname` varchar(10) NOT NULL,
PRIMARY KEY (`cname`)
) ENGINE=InnoDB DEFAULT CHARSET=latin1;
-- Table structure for table `classseats`
CREATE TABLE IF NOT EXISTS `classseats` (
`trainno` int(11) NOT NULL,
`doj` date NOT NULL,
`class` varchar(10) NOT NULL,
`fare` int(11) NOT NULL,
`seatsleft` int(11) NOT NULL,
PRIMARY KEY (`trainno`,`doj`,`class`),
KEY `class` (`class`)
) ENGINE=InnoDB DEFAULT CHARSET=latin1;
-- Triggers `classseats`
DROP TRIGGER IF EXISTS `before_insert_on_classseats`;
DELIMITER //
CREATE TRIGGER `before_insert_on_classseats` BEFORE INSERT ON `classseats`
FOR EACH ROW begin
if datediff(curdate(),new.doj)>0 then
SIGNAL SQLSTATE '45000'
SET MESSAGE_TEXT = 'Check date!!!';
end if;
if new.fare<=0 then
SIGNAL SQLSTATE '45000'
SET MESSAGE_TEXT = 'Check fare!!!';
end if;
if new.seatsleft<=0 then
SIGNAL SQLSTATE '45000'
SET MESSAGE_TEXT = 'Check seats!!!';
end if;
end
//
DELIMITER ;
DROP TRIGGER IF EXISTS `before_update_on_classseats`;
DELIMITER //
CREATE TRIGGER `before_update_on_classseats` BEFORE UPDATE ON `classseats`
FOR EACH ROW begin
if datediff(curdate(),new.doj)>0 then
SIGNAL SQLSTATE '45000'
SET MESSAGE_TEXT = 'check date!!!';
end if;
if new.fare<=0 then
SIGNAL SQLSTATE '45000'
SET MESSAGE_TEXT = 'Check fare!!!';
end if;
if new.seatsleft<=0 then
SIGNAL SQLSTATE '45000'
SET MESSAGE_TEXT = 'Check seats!!!';
end if;
end
//
DELIMITER ;
-- Table structure for table `pd`
CREATE TABLE IF NOT EXISTS `pd` (
`pnr` int(11) NOT NULL,
`pname` varchar(50) NOT NULL,
`page` int(11) NOT NULL,
`pgender` varchar(10) NOT NULL,
PRIMARY KEY (`pnr`,`pname`,`page`,`pgender`)
) ENGINE=InnoDB DEFAULT CHARSET=latin1;
-- Triggers `pd`
--
DROP TRIGGER IF EXISTS `before_insert_on_pd`;
DELIMITER //
CREATE TRIGGER `before_insert_on_pd` BEFORE INSERT ON `pd`
FOR EACH ROW begin
if new.pgender NOT IN ('M','F') then
SIGNAL SQLSTATE '45000'
SET MESSAGE_TEXT = 'Enter M:Male F:Female.';
end if;
end
//
DELIMITER ;
DROP TRIGGER IF EXISTS `before_update_on_pd`;
DELIMITER //
CREATE TRIGGER `before_update_on_pd` BEFORE UPDATE ON `pd`
FOR EACH ROW begin
if new.pgender NOT IN ('M','F') then
SIGNAL SQLSTATE '45000'
SET MESSAGE_TEXT = 'Enter M:Male F:Female.';
end if;
end
//
DELIMITER ;
-- Table structure for table `resv'
CREATE TABLE IF NOT EXISTS `resv` (
`pnr` int(11) NOT NULL AUTO_INCREMENT,
`id` int(11) NOT NULL,
`trainno` int(11) NOT NULL,
`doj` date NOT NULL,
`tfare` int(11) NOT NULL,
`class` varchar(50) NOT NULL,
`nos` int(11) NOT NULL,
`status` varchar(50) NOT NULL,
PRIMARY KEY (`pnr`),
UNIQUE KEY `UNIQUE` (`id`,`trainno`,`doj`,`status`),
KEY `FK_ID` (`id`),
KEY `FK_TN_DOJ_C` (`trainno`,`doj`,`class`),
KEY `class` (`class`)
) ENGINE=InnoDB DEFAULT CHARSET=latin1 AUTO_INCREMENT=41 ;
-- Triggers `resv`
DROP TRIGGER IF EXISTS `after_insert_on_resv`;
DELIMITER //
CREATE TRIGGER `after_insert_on_resv` AFTER INSERT ON `resv`
FOR EACH ROW begin
UPDATE classseats SET seatsleft=seatsleft-new.nos where trainno=new.trainno AND class=new.class AND doj=new.doj;
end
//
DELIMITER ;
DROP TRIGGER IF EXISTS `after_update_on_resv`;
DELIMITER //
CREATE TRIGGER `after_update_on_resv` AFTER UPDATE ON `resv`
FOR EACH ROW begin
if (new.status='CANCELLED' AND datediff(new.doj,curdate())<=0 ) then
SIGNAL SQLSTATE '45000'
SET MESSAGE_TEXT = 'Cancellation Not Possible!!!!';
end if;
if (new.status='CANCELLED' AND datediff(new.doj,curdate())>0 )then
UPDATE classseats SET seatsleft=seatsleft+new.nos where trainno=new.trainno AND class=new.class AND doj=new.doj;
if datediff(new.doj,curdate())>=30 then
INSERT INTO canc values (new.pnr,new.tfare);
end if;
if datediff(new.doj,curdate())<30 then
INSERT INTO canc values (new.pnr,0.5*new.tfare);
end if;
end if;
end
//
DELIMITER ;
DROP TRIGGER IF EXISTS `before_insert_on_resv`;
DELIMITER //
CREATE TRIGGER `before_insert_on_resv` BEFORE INSERT ON `resv`
FOR EACH ROW begin
if new.tfare<0 then
SIGNAL SQLSTATE '45000'
SET MESSAGE_TEXT = 'Negative balance NOT possible';
end if;
if new.nos<=0 then
SIGNAL SQLSTATE '45000'
SET MESSAGE_TEXT = 'Negative OR 0 seats NOT possible';
end if;
if (select seatsleft from classseats where trainno=new.trainno AND class=new.class AND doj=new.doj) < new.nos then
SIGNAL SQLSTATE '45000'
SET MESSAGE_TEXT = 'Not enough seats available!!!';
end if;
SET new.status='BOOKED';
end
//
DELIMITER ;
DROP TRIGGER IF EXISTS `before_update_on_resv`;
DELIMITER //
CREATE TRIGGER `before_update_on_resv` BEFORE UPDATE ON `resv`
FOR EACH ROW begin
if new.tfare<0 then
SIGNAL SQLSTATE '45000'
SET MESSAGE_TEXT = 'Negative balance NOT possible';
end if;
if new.nos<=0 then
SIGNAL SQLSTATE '45000'
SET MESSAGE_TEXT = 'Negative OR 0 seats NOT possible';
end if;
if (select seatsleft from classseats where trainno=new.trainno AND class=new.class AND doj=new.doj) < new.nos then
SIGNAL SQLSTATE '45000'
SET MESSAGE_TEXT = 'Not enough seats available!!!';
end if;
end
//
DELIMITER ;
-- Table structure for table `station`
CREATE TABLE IF NOT EXISTS `station` (
`sname` varchar(50) NOT NULL,
PRIMARY KEY (`sname`)
) ENGINE=InnoDB DEFAULT CHARSET=latin1;
-- Table structure for table `train`
CREATE TABLE IF NOT EXISTS `train` (
`trainno` int(11) NOT NULL AUTO_INCREMENT,
`tname` varchar(50) NOT NULL,
`sp` varchar(50) NOT NULL,
`st` time NOT NULL,
`dp` varchar(50) NOT NULL,
`dd` varchar(10) DEFAULT NULL,
`dt` time NOT NULL,
PRIMARY KEY (`trainno`),
KEY `sp` (`sp`),
KEY `dp` (`dp`)
) ENGINE=InnoDB DEFAULT CHARSET=latin1 AUTO_INCREMENT=11 ;
-- Triggers `train`
DROP TRIGGER IF EXISTS `before_insert_on_train`;
DELIMITER //
CREATE TRIGGER `before_insert_on_train` BEFORE INSERT ON `train`
FOR EACH ROW begin
if (new.dt<new.st AND new.dd='Day 1') then
SIGNAL SQLSTATE '45000'
SET MESSAGE_TEXT = 'Improper Timings';
end if;
if (new.dp=new.sp) then
SIGNAL SQLSTATE '45000'
SET MESSAGE_TEXT = 'Same Starting & Destination Points not allowed';
end if;
end
//
DELIMITER ;
DROP TRIGGER IF EXISTS `before_update_on_train`;
DELIMITER //
CREATE TRIGGER `before_update_on_train` BEFORE UPDATE ON `train`
FOR EACH ROW begin
if (new.dt<new.st AND new.dd='Day 1') then
SIGNAL SQLSTATE '45000'
SET MESSAGE_TEXT = 'Improper Timings';
end if;
end
//
DELIMITER ;
-- Table structure for table `user`
CREATE TABLE IF NOT EXISTS `user` (
`id` int(11) NOT NULL AUTO_INCREMENT,
`password` varchar(50) NOT NULL,
`emailid` varchar(50) NOT NULL,
`mobileno` varchar(10) NOT NULL,
`dob` date NOT NULL,
PRIMARY KEY (`id`),
UNIQUE KEY `UNIQUEMN` (`mobileno`),
UNIQUE KEY `UNIQUEEI` (`emailid`)
) ENGINE=InnoDB DEFAULT CHARSET=latin1 AUTO_INCREMENT=23 ;
-- Triggers `user`
DROP TRIGGER IF EXISTS `before_insert_on_user`;
DELIMITER //
CREATE TRIGGER `before_insert_on_user` BEFORE INSERT ON `user`
FOR EACH ROW begin
if (year(curdate())-year(new.dob))<18 then
SIGNAL SQLSTATE '45000'
SET MESSAGE_TEXT = 'Minimum age bar of 18 years.';
end if;
end
//
DELIMITER ;
DROP TRIGGER IF EXISTS `before_update_on_user`;
DELIMITER //
CREATE TRIGGER `before_update_on_user` BEFORE UPDATE ON `user`
FOR EACH ROW begin
if (year(curdate())-year(new.dob))<18 then
SIGNAL SQLSTATE '45000'
SET MESSAGE_TEXT = 'Minimum age bar of 18 years.';
end if;
end
//
DELIMITER ;
-- Constraints for table `canc`
ALTER TABLE `canc`
ADD CONSTRAINT `canc_ibfk_1` FOREIGN KEY (`pnr`) REFERENCES `resv` (`pnr`) ON UPDATE CASCADE;
-- Constraints for table `classseats`
ALTER TABLE `classseats`
ADD CONSTRAINT `classseats_ibfk_1` FOREIGN KEY (`trainno`) REFERENCES `train` (`trainno`) ON UPDATE CASCADE,
ADD CONSTRAINT `classseats_ibfk_2` FOREIGN KEY (`class`) REFERENCES `class` (`cname`) ON UPDATE CASCADE;
-- Constraints for table `pd`
ALTER TABLE `pd`
ADD CONSTRAINT `pd_ibfk_1` FOREIGN KEY (`pnr`) REFERENCES `resv` (`pnr`) ON UPDATE CASCADE;
-- Constraints for table `resv`
ALTER TABLE `resv`
ADD CONSTRAINT `resv_ibfk_1` FOREIGN KEY (`id`) REFERENCES `user` (`id`) ON UPDATE CASCADE,
ADD CONSTRAINT `resv_ibfk_2` FOREIGN KEY (`trainno`, `doj`, `class`) REFERENCES `classseats` (`trainno`, `doj`, `class`) ON UPDATE CASCADE,
ADD CONSTRAINT `resv_ibfk_3` FOREIGN KEY (`class`) REFERENCES `class` (`cname`) ON UPDATE CASCADE;
-- Constraints for table `train`
ALTER TABLE `train`
ADD CONSTRAINT `train_ibfk_1` FOREIGN KEY (`sp`) REFERENCES `station` (`sname`) ON UPDATE CASCADE,
ADD CONSTRAINT `train_ibfk_2` FOREIGN KEY (`dp`) REFERENCES `station` (`sname`) ON UPDATE CASCADE;