P2: schema_creation.sql

File schema_creation.sql, 7.4 KB (added by 193284, 11 days ago)

Script for creating/recreating the database schema, tables and constraints.

Line 
1DROP SCHEMA IF EXISTS project CASCADE;
2CREATE SCHEMA project;
3SET search_path TO project;
4
5CREATE TABLE "user" (
6 user_id SERIAL PRIMARY KEY,
7 first_name VARCHAR(50) NOT NULL,
8 last_name VARCHAR(50) NOT NULL,
9 email VARCHAR(120) NOT NULL UNIQUE,
10 phone_number VARCHAR(30),
11 gender VARCHAR(20),
12 birthday DATE
13);
14
15CREATE TABLE wedding (
16 wedding_id SERIAL PRIMARY KEY,
17 "date" DATE NOT NULL,
18 budget NUMERIC(12,2),
19 notes TEXT,
20 user_id INTEGER NOT NULL,
21 CONSTRAINT fk_wedding_user
22 FOREIGN KEY (user_id) REFERENCES "user"(user_id)
23 ON UPDATE CASCADE
24 ON DELETE CASCADE
25);
26
27CREATE TABLE church (
28 church_id SERIAL PRIMARY KEY,
29 name VARCHAR(120) NOT NULL,
30 location VARCHAR(150) NOT NULL,
31 contact VARCHAR(120) NOT NULL,
32 wedding_id INTEGER UNIQUE,
33 CONSTRAINT fk_church_wedding
34 FOREIGN KEY (wedding_id) REFERENCES wedding(wedding_id)
35 ON UPDATE CASCADE
36 ON DELETE SET NULL
37);
38
39CREATE TABLE priest (
40 priest_id SERIAL PRIMARY KEY,
41 name VARCHAR(120) NOT NULL,
42 contact VARCHAR(120) NOT NULL,
43 church_id INTEGER NOT NULL,
44 CONSTRAINT fk_priest_church
45 FOREIGN KEY (church_id) REFERENCES church(church_id)
46 ON UPDATE CASCADE
47 ON DELETE CASCADE
48);
49
50CREATE TABLE event (
51 event_id SERIAL PRIMARY KEY,
52 event_type VARCHAR(60) NOT NULL,
53 "date" DATE NOT NULL,
54 start_time TIME NOT NULL,
55 end_time TIME NOT NULL,
56 status VARCHAR(30) NOT NULL,
57 wedding_id INTEGER NOT NULL,
58 CONSTRAINT fk_event_wedding
59 FOREIGN KEY (wedding_id) REFERENCES wedding(wedding_id)
60 ON UPDATE CASCADE
61 ON DELETE CASCADE,
62 CONSTRAINT chk_event_time
63 CHECK (end_time > start_time)
64);
65
66CREATE TABLE guest (
67 guest_id SERIAL PRIMARY KEY,
68 first_name VARCHAR(50) NOT NULL,
69 last_name VARCHAR(50) NOT NULL,
70 email VARCHAR(120),
71 wedding_id INTEGER NOT NULL,
72 CONSTRAINT fk_guest_wedding
73 FOREIGN KEY (wedding_id) REFERENCES wedding(wedding_id)
74 ON UPDATE CASCADE
75 ON DELETE CASCADE
76);
77
78CREATE TABLE event_rsvp (
79 response_id SERIAL PRIMARY KEY,
80 status VARCHAR(30) NOT NULL,
81 response_date DATE NOT NULL,
82 guest_id INTEGER NOT NULL,
83 event_id INTEGER NOT NULL,
84 CONSTRAINT fk_rsvp_guest
85 FOREIGN KEY (guest_id) REFERENCES guest(guest_id)
86 ON UPDATE CASCADE
87 ON DELETE CASCADE,
88 CONSTRAINT fk_rsvp_event
89 FOREIGN KEY (event_id) REFERENCES event(event_id)
90 ON UPDATE CASCADE
91 ON DELETE CASCADE,
92 CONSTRAINT uq_rsvp_guest_event UNIQUE (guest_id, event_id)
93);
94
95CREATE TABLE attendance (
96 attendance_id SERIAL PRIMARY KEY,
97 status VARCHAR(30) NOT NULL,
98 table_number INTEGER,
99 role VARCHAR(40) NOT NULL,
100 guest_id INTEGER NOT NULL,
101 event_id INTEGER NOT NULL,
102 CONSTRAINT fk_att_guest
103 FOREIGN KEY (guest_id) REFERENCES guest(guest_id)
104 ON UPDATE CASCADE
105 ON DELETE CASCADE,
106 CONSTRAINT fk_att_event
107 FOREIGN KEY (event_id) REFERENCES event(event_id)
108 ON UPDATE CASCADE
109 ON DELETE CASCADE,
110 CONSTRAINT uq_att_guest_event UNIQUE (guest_id, event_id),
111 CONSTRAINT chk_table_number
112 CHECK (table_number IS NULL OR table_number > 0)
113);
114
115CREATE TABLE venue_type (
116 type_id SERIAL PRIMARY KEY,
117 type_name VARCHAR(50) NOT NULL UNIQUE
118);
119
120CREATE TABLE venue (
121 venue_id SERIAL PRIMARY KEY,
122 name VARCHAR(120) NOT NULL,
123 location VARCHAR(150) NOT NULL,
124 city VARCHAR(80) NOT NULL,
125 address VARCHAR(150) NOT NULL,
126 capacity INTEGER NOT NULL,
127 menu TEXT,
128 phone_number VARCHAR(30),
129 price_per_guest NUMERIC(10,2) NOT NULL,
130 type_id INTEGER NOT NULL,
131 CONSTRAINT fk_venue_type
132 FOREIGN KEY (type_id) REFERENCES venue_type(type_id)
133 ON UPDATE CASCADE
134 ON DELETE RESTRICT,
135 CONSTRAINT chk_capacity
136 CHECK (capacity > 0),
137 CONSTRAINT chk_price_per_guest
138 CHECK (price_per_guest >= 0)
139);
140
141CREATE TABLE venue_booking (
142 booking_id SERIAL PRIMARY KEY,
143 "date" DATE NOT NULL,
144 start_time TIME NOT NULL,
145 end_time TIME NOT NULL,
146 status VARCHAR(30) NOT NULL,
147 price NUMERIC(12,2) NOT NULL,
148 venue_id INTEGER NOT NULL,
149 wedding_id INTEGER NOT NULL,
150 CONSTRAINT fk_vb_venue
151 FOREIGN KEY (venue_id) REFERENCES venue(venue_id)
152 ON UPDATE CASCADE
153 ON DELETE CASCADE,
154 CONSTRAINT fk_vb_wedding
155 FOREIGN KEY (wedding_id) REFERENCES wedding(wedding_id)
156 ON UPDATE CASCADE
157 ON DELETE CASCADE,
158 CONSTRAINT chk_vb_time
159 CHECK (end_time > start_time)
160);
161
162CREATE TABLE photographer (
163 photographer_id SERIAL PRIMARY KEY,
164 name VARCHAR(120) NOT NULL,
165 email VARCHAR(120) NOT NULL UNIQUE,
166 phone_number VARCHAR(30) NOT NULL,
167 price_per_hour NUMERIC(10,2) NOT NULL,
168 CONSTRAINT chk_ph_price CHECK (price_per_hour >= 0)
169);
170
171CREATE TABLE photographer_booking (
172 booking_id SERIAL PRIMARY KEY,
173 "date" DATE NOT NULL,
174 start_time TIME NOT NULL,
175 end_time TIME NOT NULL,
176 status VARCHAR(30) NOT NULL,
177 photographer_id INTEGER NOT NULL,
178 wedding_id INTEGER NOT NULL,
179 CONSTRAINT fk_pb_photographer
180 FOREIGN KEY (photographer_id) REFERENCES photographer(photographer_id)
181 ON UPDATE CASCADE
182 ON DELETE CASCADE,
183 CONSTRAINT fk_pb_wedding
184 FOREIGN KEY (wedding_id) REFERENCES wedding(wedding_id)
185 ON UPDATE CASCADE
186 ON DELETE CASCADE,
187 CONSTRAINT chk_pb_time CHECK (end_time > start_time)
188);
189
190CREATE TABLE band (
191 band_id SERIAL PRIMARY KEY,
192 band_name VARCHAR(120) NOT NULL,
193 genre VARCHAR(60) NOT NULL,
194 equipment TEXT,
195 phone_number VARCHAR(30) NOT NULL,
196 price_per_hour NUMERIC(10,2) NOT NULL,
197 CONSTRAINT chk_band_price CHECK (price_per_hour >= 0)
198);
199
200CREATE TABLE band_booking (
201 booking_id SERIAL PRIMARY KEY,
202 "date" DATE NOT NULL,
203 start_time TIME NOT NULL,
204 end_time TIME NOT NULL,
205 status VARCHAR(30) NOT NULL,
206 band_id INTEGER NOT NULL,
207 wedding_id INTEGER NOT NULL,
208 CONSTRAINT fk_bb_band
209 FOREIGN KEY (band_id) REFERENCES band(band_id)
210 ON UPDATE CASCADE
211 ON DELETE CASCADE,
212 CONSTRAINT fk_bb_wedding
213 FOREIGN KEY (wedding_id) REFERENCES wedding(wedding_id)
214 ON UPDATE CASCADE
215 ON DELETE CASCADE,
216 CONSTRAINT chk_bb_time CHECK (end_time > start_time)
217);
218
219CREATE INDEX idx_wedding_user ON wedding(user_id);
220CREATE INDEX idx_event_wedding ON event(wedding_id);
221CREATE INDEX idx_guest_wedding ON guest(wedding_id);
222CREATE INDEX idx_vb_wedding ON venue_booking(wedding_id);
223CREATE INDEX idx_vb_venue ON venue_booking(venue_id);
224CREATE INDEX idx_pb_wedding ON photographer_booking(wedding_id);
225CREATE INDEX idx_bb_wedding ON band_booking(wedding_id);