RelationalDesign: ddl-v1.sql

File ddl-v1.sql, 4.9 KB (added by 231136, 4 hours ago)
Line 
1DROP TABLE IF EXISTS ARTIST_CONTRIBUTIONS;
2DROP TABLE IF EXISTS PLAYLIST_SONGS;
3DROP TABLE IF EXISTS SAVED_PLAYLISTS;
4DROP TABLE IF EXISTS REVIEWS;
5DROP TABLE IF EXISTS LISTENS;
6DROP TABLE IF EXISTS LIKES;
7DROP TABLE IF EXISTS PERFORMS_AT;
8DROP TABLE IF EXISTS FOLLOWS;
9DROP TABLE IF EXISTS PLAYLISTS;
10DROP TABLE IF EXISTS EVENTS;
11DROP TABLE IF EXISTS SONGS;
12DROP TABLE IF EXISTS ALBUMS;
13DROP TABLE IF EXISTS MUSICAL_ENTITIES;
14DROP TABLE IF EXISTS ARTISTS;
15DROP TABLE IF EXISTS LISTENERS;
16DROP TABLE IF EXISTS ADMINS;
17DROP TABLE IF EXISTS NON_ADMIN_USERS;
18DROP TABLE IF EXISTS USERS;
19
20
21
22drop schema if exists finkwave cascade;
23
24create schema finkwave;
25
26
27CREATE TABLE USERS (
28 user_id BIGINT PRIMARY KEY,
29 full_name TEXT NOT NULL,
30 email TEXT NOT NULL,
31 password TEXT NOT NULL,
32 username TEXT NOT NULL,
33 profile_photo TEXT
34);
35
36CREATE TABLE NON_ADMIN_USERS (
37 user_id BIGINT PRIMARY KEY REFERENCES USERS(user_id) ON DELETE CASCADE
38);
39
40CREATE TABLE ADMINS (
41 user_id BIGINT PRIMARY KEY REFERENCES USERS(user_id) ON DELETE CASCADE
42);
43
44CREATE TABLE LISTENERS (
45 user_id BIGINT PRIMARY KEY REFERENCES USERS(user_id) ON DELETE CASCADE
46);
47
48CREATE TABLE ARTISTS (
49 user_id BIGINT PRIMARY KEY REFERENCES USERS(user_id) ON DELETE CASCADE
50);
51
52CREATE TABLE MUSICAL_ENTITIES (
53 id BIGINT PRIMARY KEY,
54 title TEXT NOT NULL,
55 genre TEXT NOT NULL,
56 release_date DATE NOT NULL,
57 released_by BIGINT REFERENCES ARTISTS(user_id) ON DELETE CASCADE
58);
59
60
61CREATE TABLE ALBUMS (
62 id BIGINT PRIMARY KEY REFERENCES MUSICAL_ENTITIES(id) ON DELETE CASCADE
63);
64
65CREATE TABLE SONGS (
66 id BIGINT PRIMARY KEY REFERENCES MUSICAL_ENTITIES(id) ON DELETE CASCADE,
67 album_id BIGINT REFERENCES ALBUMS(id) ON DELETE CASCADE,
68-- modified_by_admin_id BIGINT REFERENCES ADMIN(user_id) ON DELETE SET NULL,
69-- removed_by_admin_id BIGINT REFERENCES ADMIN(user_id) ON DELETE SET NULL,
70 link TEXT NOT NULL
71);
72
73
74
75CREATE TABLE EVENTS (
76 event_id BIGINT PRIMARY KEY,
77 location TEXT NOT NULL,
78 venue TEXT NOT NULL,
79 creator_artist_id BIGINT REFERENCES ARTISTS(user_id) ON DELETE CASCADE,
80 creator_admin_id BIGINT REFERENCES ADMINS (user_id) ON DELETE CASCADE,
81
82 CONSTRAINT has_exactly_one_creator
83 CHECK ((creator_artist_id is not null and creator_admin_id is null) OR
84 (creator_artist_id is null and creator_admin_id is not null))
85);
86
87CREATE TABLE PLAYLISTS (
88 playlist_id BIGINT PRIMARY KEY,
89 cover TEXT,
90 name TEXT NOT NULL,
91 created_by BIGINT REFERENCES LISTENERS(user_id) ON DELETE CASCADE
92);
93
94-- RELACII
95
96
97CREATE TABLE FOLLOWS (
98 follower BIGINT REFERENCES NON_ADMIN_USERS(user_id) ON DELETE CASCADE,
99 followee BIGINT REFERENCES NON_ADMIN_USERS(user_id) ON DELETE CASCADE,
100
101 CONSTRAINT follows_no_self_follow
102 CHECK (follower <> followee),
103
104 CONSTRAINT follows_pk
105 PRIMARY KEY (follower, followee)
106);
107
108CREATE TABLE PERFORMS_AT (
109 event_id BIGINT REFERENCES EVENTS(event_id) ON DELETE CASCADE,
110 artist_id BIGINT REFERENCES ARTISTS(user_id) ON DELETE CASCADE,
111
112 CONSTRAINT performs_at_pk
113 PRIMARY KEY (event_id, artist_id)
114);
115
116CREATE TABLE LIKES (
117 listener_id BIGINT REFERENCES LISTENERS(user_id) ON DELETE CASCADE,
118 musical_entity_id BIGINT REFERENCES MUSICAL_ENTITIES(id) ON DELETE CASCADE,
119
120 CONSTRAINT likes_pk
121 PRIMARY KEY (listener_id, musical_entity_id)
122);
123
124CREATE TABLE LISTENS (
125 listener_id BIGINT REFERENCES LISTENERS(user_id) ON DELETE CASCADE,
126 song_id BIGINT REFERENCES SONGS(id) ON DELETE CASCADE,
127 listen_count INT NOT NULL DEFAULT 1,
128
129 CONSTRAINT listens_to_pk
130 PRIMARY KEY (listener_id, song_id)
131);
132
133CREATE TABLE REVIEWS (
134 listener_id BIGINT REFERENCES LISTENERS(user_id) ON DELETE CASCADE,
135 musical_entity_id BIGINT REFERENCES MUSICAL_ENTITIES(id) ON DELETE CASCADE,
136 grade INT CHECK ( grade between 1 and 5) NOT NULL,
137 comment TEXT,
138
139 CONSTRAINT reviews_pk
140 PRIMARY KEY (listener_id, musical_entity_id)
141);
142
143CREATE TABLE SAVED_PLAYLISTS (
144 listener_id BIGINT REFERENCES LISTENERS(user_id) ON DELETE CASCADE,
145 playlist_id BIGINT REFERENCES PLAYLISTS(playlist_id) ON DELETE CASCADE,
146
147 CONSTRAINT saved_playlists_id
148 PRIMARY KEY (listener_id, playlist_id)
149);
150
151CREATE TABLE PLAYLIST_SONGS (
152 song_id BIGINT REFERENCES SONGS(id) ON DELETE CASCADE,
153 playlist_id BIGINT REFERENCES PLAYLISTS(playlist_id) ON DELETE CASCADE,
154
155 CONSTRAINT playlist_songs_id
156 PRIMARY KEY (song_id, playlist_id)
157);
158
159CREATE TABLE ARTIST_CONTRIBUTIONS (
160 artist_id BIGINT REFERENCES ARTISTS(user_id) ON DELETE CASCADE,
161 musical_entity_id BIGINT REFERENCES MUSICAL_ENTITIES(id) ON DELETE CASCADE,
162 role TEXT NOT NULL,
163
164 CONSTRAINT artist_contribution_id
165 PRIMARY KEY (artist_id, musical_entity_id)
166);