Schema Version 1.3

Renamed artist.description to artist.name
master
Peery 3 years ago
parent 9e66557e35
commit 637f74fbe6

@ -0,0 +1,96 @@
-- Creating the DB structure
-- Version 1.3 (2021-08-14)
CREATE TABLE IF NOT EXISTS Art (
ID INTEGER PRIMARY KEY generated always as identity,
md5_hash CHAR(32) NOT NULL UNIQUE,
path VARCHAR NOT NULL UNIQUE,
title VARCHAR,
link VARCHAR
);
CREATE TABLE IF NOT EXISTS Artist (
ID INTEGER PRIMARY KEY generated always as identity,
name VARCHAR -- used as artists name
);
CREATE TABLE IF NOT EXISTS Topic ( -- as of yet unimplemented, see Art_Topic
id INTEGER PRIMARY KEY generated always as identity,
name CHAR(20) UNIQUE NOT NULL,
description VARCHAR
);
CREATE TABLE IF NOT EXISTS Presence (
name CHAR(20) NOT NULL,
domain CHAR(20) NOT NULL,
link VARCHAR,
artist_ID INTEGER NOT NULL,
PRIMARY KEY (name, domain),
FOREIGN KEY (artist_ID) REFERENCES Artist(ID) ON DELETE CASCADE
);
CREATE TABLE IF NOT EXISTS Art_Author (
presence_name CHAR(20) NOT NULL,
presence_domain CHAR(20) NOT NULL,
art_ID INTEGER NOT NULL,
PRIMARY KEY (presence_name, presence_domain, art_ID),
FOREIGN KEY (presence_name, presence_domain) REFERENCES Presence(name, domain) ON UPDATE CASCADE ON DELETE CASCADE,
FOREIGN KEY (art_ID) REFERENCES Art(ID) ON UPDATE CASCADE ON DELETE CASCADE
);
CREATE TABLE IF NOT EXISTS Artist_Topic ( -- TODO implement, meant to indicate an artists main topics
artist_ID INTEGER NOT NULL,
topic_ID INTEGER NOT NULL,
PRIMARY KEY (artist_ID, topic_ID),
FOREIGN KEY (artist_ID) REFERENCES Artist(ID) ON UPDATE CASCADE ON DELETE CASCADE,
FOREIGN KEY (topic_ID) REFERENCES Topic(ID) ON UPDATE CASCADE ON DELETE CASCADE
);
CREATE TABLE IF NOT EXISTS tag_category (
category_id INTEGER PRIMARY KEY generated always as identity,
name CHAR(20) NOT NULL
);
CREATE TABLE IF NOT EXISTS tag (
tag_ID INTEGER PRIMARY KEY generated always as identity,
name CHAR(50) UNIQUE,
description VARCHAR,
category_id SERIAL,
FOREIGN KEY (category_id) REFERENCES tag_category(category_id)
);
CREATE TABLE IF NOT EXISTS Art_Tag (
art_ID INTEGER,
tag_ID INTEGER,
PRIMARY KEY (art_ID, tag_ID),
FOREIGN KEY(art_ID) REFERENCES Art(ID) ON DELETE CASCADE,
FOREIGN KEY (tag_ID) REFERENCES tag(tag_ID) ON DELETE CASCADE
);
CREATE TABLE IF NOT EXISTS Tag_Alias (
tag1 INTEGER,
tag2 INTEGER,
PRIMARY KEY (tag1, tag2),
FOREIGN KEY (tag1) REFERENCES tag(tag_ID) ON DELETE CASCADE,
FOREIGN KEY (tag2) REFERENCES tag(tag_ID) ON DELETE CASCADE
);
CREATE TABLE IF NOT EXISTS Tag_Implication (
root_tag INTEGER,
implicate INTEGER,
PRIMARY KEY (root_tag, implicate),
FOREIGN KEY (root_tag) REFERENCES tag(tag_ID) ON DELETE CASCADE,
FOREIGN KEY (implicate) REFERENCES tag(tag_ID) ON DELETE CASCADE
);
-- Granting appropriate permissions for the user artnet_editor (editing, deleting, reading, inserting)
GRANT CONNECT ON
DATABASE artnet
TO artnet_editor;
GRANT SELECT, INSERT, UPDATE, DELETE ON
TABLE art, art_author, tag_category, art_tag, artist_topic, artist, presence, tag, tag_alias, tag_implication, topic
TO artnet_editor;
GRANT USAGE ON
SEQUENCE art_id_seq, artist_id_seq, tag_tag_id_seq
TO artnet_editor;

@ -0,0 +1,14 @@
DROP TABLE IF EXISTS Art CASCADE;
DROP TABLE IF EXISTS Artist CASCADE;
DROP TABLE IF EXISTS Presence CASCADE;
DROP TABLE IF EXISTS Topic CASCADE;
DROP TABLE IF EXISTS Art_Author CASCADE;
DROP TABLE IF EXISTS Art_Topic CASCADE;
DROP TABLE IF EXISTS tag CASCADE;
DROP TABLE IF EXISTS Art_Tag CASCADE;
DROP TABLE IF EXISTS Tag_Implication CASCADE;
DROP TABLE IF EXISTS Tag_Alias CASCADE;
DROP TABLE IF EXISTS tag_category CASCADE;
Loading…
Cancel
Save