ddlScript: travel_sage_ddl.sql

File travel_sage_ddl.sql, 5.5 KB (added by 223270, 3 weeks ago)
Line 
1CREATE SCHEMA IF NOT EXISTS travel_sage;
2SET search_path TO travel_sage;
3
4DROP TABLE IF EXISTS destination_user CASCADE;
5DROP TABLE IF EXISTS activity_reservation CASCADE;
6DROP TABLE IF EXISTS package_reservation CASCADE;
7DROP TABLE IF EXISTS package_activity CASCADE;
8DROP TABLE IF EXISTS preference CASCADE;
9DROP TABLE IF EXISTS destination_tag CASCADE;
10DROP TABLE IF EXISTS tag CASCADE;
11DROP TABLE IF EXISTS event CASCADE;
12DROP TABLE IF EXISTS activity CASCADE;
13DROP TABLE IF EXISTS package CASCADE;
14DROP TABLE IF EXISTS meteorological_condition CASCADE;
15DROP TABLE IF EXISTS review CASCADE;
16DROP TABLE IF EXISTS reservation CASCADE;
17DROP TABLE IF EXISTS premium CASCADE;
18DROP TABLE IF EXISTS standard CASCADE;
19DROP TABLE IF EXISTS users CASCADE;
20DROP TABLE IF EXISTS destination CASCADE;
21
22CREATE TABLE IF NOT EXISTS destination (
23 id_destination SERIAL PRIMARY KEY,
24 location_name VARCHAR(255) NOT NULL,
25 location_desc TEXT,
26 types_of_places TEXT,
27 recommended_season TEXT,
28 average_temp NUMERIC(5,2),
29 latitude DECIMAL(9,6),
30 longitude DECIMAL(9,6),
31 country VARCHAR(100),
32 popularity INTEGER DEFAULT 0,
33 important_location_name VARCHAR(255),
34 important_location_description TEXT
35);
36
37CREATE TABLE IF NOT EXISTS users (
38 id_user SERIAL PRIMARY KEY,
39 first_name VARCHAR(100) NOT NULL,
40 last_name VARCHAR(100) NOT NULL,
41 email VARCHAR(255) NOT NULL UNIQUE,
42 phone_number VARCHAR(30),
43 birth_date DATE,
44 is_premium BOOLEAN NOT NULL DEFAULT FALSE
45);
46
47CREATE TABLE IF NOT EXISTS standard (
48 id_user INT PRIMARY KEY REFERENCES users(id_user) ON DELETE CASCADE
49);
50
51CREATE TABLE IF NOT EXISTS premium (
52 id_user INT PRIMARY KEY REFERENCES users(id_user) ON DELETE CASCADE,
53 date_created TIMESTAMP NOT NULL DEFAULT now(),
54 discount NUMERIC(5,2)
55);
56
57CREATE TABLE IF NOT EXISTS reservation (
58 id_reservation SERIAL PRIMARY KEY,
59 id_user INT NOT NULL REFERENCES users(id_user) ON DELETE CASCADE,
60 time_point TIMESTAMP NOT NULL DEFAULT now(),
61 premium_discount_applied BOOLEAN NOT NULL DEFAULT FALSE,
62 discount_amount NUMERIC(5,2) NOT NULL,
63 total_price NUMERIC(12,2) NOT NULL
64);
65
66CREATE TABLE IF NOT EXISTS review (
67 id_review SERIAL PRIMARY KEY,
68 username VARCHAR(255) NOT NULL,
69 reservation_id INT UNIQUE REFERENCES reservation(id_reservation) ON DELETE CASCADE,
70 id_destination INT NOT NULL REFERENCES destination(id_destination) ON DELETE CASCADE,
71 quality SMALLINT NOT NULL CHECK (quality BETWEEN 1 AND 5),
72 comment TEXT,
73 review_date TIMESTAMP DEFAULT now(),
74 vote_count INTEGER DEFAULT 0
75);
76
77CREATE TABLE IF NOT EXISTS meteorological_condition (
78 id_meteo SERIAL PRIMARY KEY,
79 id_destination INT NOT NULL REFERENCES destination(id_destination) ON DELETE CASCADE,
80 current_temp NUMERIC(5,2) NOT NULL,
81 weather_condition VARCHAR(50) NOT NULL,
82 warnings VARCHAR(100) NOT NULL,
83 humidity NUMERIC(5,2),
84 wind NUMERIC(6,2),
85 month SMALLINT
86);
87
88CREATE TABLE IF NOT EXISTS package (
89 id_package SERIAL PRIMARY KEY,
90 package_name VARCHAR(255) NOT NULL,
91 id_destination INT NOT NULL REFERENCES destination(id_destination) ON DELETE CASCADE,
92 price NUMERIC(12,2) NOT NULL,
93 start_date DATE NOT NULL,
94 end_date DATE NOT NULL
95);
96
97CREATE TABLE IF NOT EXISTS activity (
98 id_activity SERIAL PRIMARY KEY,
99 activity_name VARCHAR(255) NOT NULL,
100 id_destination INT REFERENCES destination(id_destination) ON DELETE CASCADE,
101 information TEXT,
102 amount NUMERIC(10,2),
103 category VARCHAR(100) NOT NULL
104);
105
106CREATE TABLE IF NOT EXISTS event (
107 id_event SERIAL PRIMARY KEY,
108 event_name VARCHAR(255) NOT NULL,
109 id_destination INT NOT NULL REFERENCES destination(id_destination) ON DELETE CASCADE,
110 start_date DATE,
111 end_date DATE,
112 details TEXT,
113 event_type TEXT NOT NULL
114);
115
116CREATE TABLE IF NOT EXISTS tag (
117 id_tag SERIAL PRIMARY KEY,
118 tag_name VARCHAR(100) NOT NULL
119);
120
121CREATE TABLE IF NOT EXISTS destination_tag (
122 id_destination INT REFERENCES destination(id_destination) ON DELETE CASCADE,
123 id_tag INT REFERENCES tag(id_tag) ON DELETE CASCADE,
124 PRIMARY KEY(id_destination, id_tag)
125);
126
127CREATE TABLE IF NOT EXISTS preference (
128 id_preference SERIAL PRIMARY KEY,
129 id_user INT NOT NULL REFERENCES users(id_user) ON DELETE CASCADE,
130 priority INT,
131 type_preference TEXT NOT NULL
132);
133
134CREATE TABLE IF NOT EXISTS package_activity (
135 id_package INT REFERENCES package(id_package) ON DELETE CASCADE,
136 id_activity INT REFERENCES activity(id_activity) ON DELETE CASCADE,
137 PRIMARY KEY(id_package, id_activity)
138);
139
140CREATE TABLE IF NOT EXISTS package_reservation (
141 id_package INT REFERENCES package(id_package) ON DELETE CASCADE,
142 id_reservation INT REFERENCES reservation(id_reservation) ON DELETE CASCADE,
143 PRIMARY KEY(id_package, id_reservation)
144);
145
146CREATE TABLE IF NOT EXISTS activity_reservation (
147 id_activity INT REFERENCES activity(id_activity) ON DELETE CASCADE,
148 id_reservation INT REFERENCES reservation(id_reservation) ON DELETE CASCADE,
149 PRIMARY KEY(id_activity, id_reservation)
150);
151
152CREATE TABLE IF NOT EXISTS destination_user (
153 id_destination INT REFERENCES destination(id_destination) ON DELETE CASCADE,
154 id_user INT REFERENCES users(id_user) ON DELETE CASCADE,
155 rating SMALLINT CHECK (rating BETWEEN 1 AND 5),
156 comment TEXT,
157 recommendation_date TIMESTAMP DEFAULT now(),
158 PRIMARY KEY(id_destination, id_user)
159);