RelationalDesign: schema_creation.sql

File schema_creation.sql, 3.9 KB (added by 213257, 2 weeks ago)
Line 
1DROP SCHEMA IF EXISTS project CASCADE;
2CREATE SCHEMA project;
3SET search_path TO project;
4
5CREATE TABLE admin (
6 admin_id VARCHAR(36) PRIMARY KEY DEFAULT gen_random_uuid()::text,
7 name VARCHAR(128) NOT NULL,
8 email VARCHAR(128) NOT NULL UNIQUE,
9 password VARCHAR(256) NOT NULL
10);
11
12CREATE TABLE architect (
13 architect_id VARCHAR(36) PRIMARY KEY DEFAULT gen_random_uuid()::text,
14 full_name VARCHAR(128) NOT NULL
15);
16
17CREATE TABLE building (
18 building_id VARCHAR(36) PRIMARY KEY DEFAULT gen_random_uuid()::text,
19 name VARCHAR(256) NOT NULL,
20 address VARCHAR(512) NOT NULL,
21 description TEXT,
22 admin_id VARCHAR(36) NOT NULL,
23 FOREIGN KEY (admin_id) REFERENCES admin(admin_id)
24);
25
26CREATE TABLE designs (
27 architect_id VARCHAR(36) NOT NULL,
28 building_id VARCHAR(36) NOT NULL,
29 PRIMARY KEY (architect_id, building_id),
30 FOREIGN KEY (architect_id) REFERENCES architect(architect_id),
31 FOREIGN KEY (building_id) REFERENCES building(building_id)
32);
33
34CREATE TABLE floor (
35 floor_id VARCHAR(36) PRIMARY KEY DEFAULT gen_random_uuid()::text,
36 floor_number INTEGER NOT NULL,
37 layout_image VARCHAR(512) NOT NULL,
38 building_id VARCHAR(36) NOT NULL,
39 admin_id VARCHAR(36) NOT NULL,
40 FOREIGN KEY (building_id) REFERENCES building(building_id),
41 FOREIGN KEY (admin_id) REFERENCES admin(admin_id),
42 UNIQUE (building_id, floor_number)
43);
44
45CREATE TABLE unit (
46 unit_id VARCHAR(36) PRIMARY KEY DEFAULT gen_random_uuid()::text,
47 unit_number VARCHAR(64) NOT NULL,
48 room_number INTEGER NOT NULL,
49 floor_area DECIMAL(10,2) NOT NULL,
50 status VARCHAR(32) NOT NULL CHECK (status IN ('Available', 'Reserved', 'Sold')) DEFAULT 'Available',
51 price DECIMAL(15,2) NOT NULL,
52 image VARCHAR(512),
53 floorplan VARCHAR(512),
54 vector_image VARCHAR(512) NOT NULL,
55 floor_id VARCHAR(36) NOT NULL,
56 admin_id VARCHAR(36) NOT NULL,
57 FOREIGN KEY (floor_id) REFERENCES floor(floor_id),
58 FOREIGN KEY (admin_id) REFERENCES admin(admin_id),
59 UNIQUE (floor_id, unit_number)
60);
61
62CREATE TABLE agent (
63 agent_id VARCHAR(36) PRIMARY KEY DEFAULT gen_random_uuid()::text,
64 name VARCHAR(256) NOT NULL,
65 email VARCHAR(256) NOT NULL UNIQUE,
66 password VARCHAR(256) NOT NULL
67);
68
69CREATE TABLE client (
70 client_id VARCHAR(36) PRIMARY KEY DEFAULT gen_random_uuid()::text,
71 name VARCHAR(128) NOT NULL,
72 email VARCHAR(256) NOT NULL UNIQUE,
73 phone VARCHAR(32) NOT NULL
74);
75
76CREATE TABLE timeslot (
77 timeslot_id VARCHAR(36) PRIMARY KEY DEFAULT gen_random_uuid()::text,
78 date DATE NOT NULL,
79 time_start TIME NOT NULL,
80 time_end TIME NOT NULL,
81 status VARCHAR(32) NOT NULL CHECK (status IN ('Available', 'Booked')) DEFAULT 'Available',
82 agent_id VARCHAR(36) NOT NULL,
83 FOREIGN KEY (agent_id) REFERENCES agent(agent_id),
84 UNIQUE (agent_id, date, time_start)
85);
86
87CREATE TABLE inquiry (
88 inquiry_id VARCHAR(36) PRIMARY KEY DEFAULT gen_random_uuid()::text,
89 message TEXT NOT NULL,
90 status VARCHAR(32) NOT NULL CHECK (status IN ('New', 'Replied', 'Closed')) DEFAULT 'New',
91 created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
92 unit_id VARCHAR(36) NOT NULL,
93 client_id VARCHAR(36) NOT NULL,
94 agent_id VARCHAR(36) NOT NULL,
95 FOREIGN KEY (unit_id) REFERENCES unit(unit_id),
96 FOREIGN KEY (client_id) REFERENCES client(client_id),
97 FOREIGN KEY (agent_id) REFERENCES agent(agent_id)
98);
99
100CREATE TABLE appointment (
101 appointment_id VARCHAR(36) PRIMARY KEY DEFAULT gen_random_uuid()::text,
102 status VARCHAR(32) NOT NULL CHECK (status IN ('Scheduled', 'Completed', 'Cancelled')) DEFAULT 'Scheduled',
103 client_id VARCHAR(36) NOT NULL,
104 unit_id VARCHAR(36) NOT NULL,
105 timeslot_id VARCHAR(36) NOT NULL,
106 agent_id VARCHAR(36) NOT NULL,
107 FOREIGN KEY (client_id) REFERENCES client(client_id),
108 FOREIGN KEY (unit_id) REFERENCES unit(unit_id),
109 FOREIGN KEY (timeslot_id) REFERENCES timeslot(timeslot_id),
110 FOREIGN KEY (agent_id) REFERENCES agent(agent_id),
111 UNIQUE (timeslot_id)
112);