-- Creating the DB structure
-- Version 2.0 (2021-10-10)
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 ,
description VARCHAR
) ;
CREATE TABLE IF NOT EXISTS Artist (
ID INTEGER PRIMARY KEY generated always as identity ,
name VARCHAR
) ;
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 ( 30 ) 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_Collection ( -- for ordered lists of art
ID INTEGER PRIMARY KEY generated always as identity ,
name VARCHAR NOT NULL UNIQUE ,
description VARCHAR
) ;
CREATE TABLE IF NOT EXISTS Art_to_Art_Collection (
collection_ID INTEGER NOT NULL ,
art_ID INTEGER NOT NULL ,
ranking VARCHAR , -- order in the collection by string value, allows easy insert see https://stackoverflow.com/questions/9536262/best-representation-of-an-ordered-list-in-a-database; same rank or empty rank means unordered
PRIMARY KEY ( collection_ID , art_ID ) ,
FOREIGN KEY ( collection_ID ) REFERENCES Art_Collection ( ID ) ON DELETE CASCADE ,
FOREIGN KEY ( art_ID ) REFERENCES Art ( ID )
) ;
CREATE TABLE IF NOT EXISTS Art_to_Presence (
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_to_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_to_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_to_presence , tag_category , art_to_tag , artist_to_topic , artist , presence , tag , tag_alias , tag_implication , topic , art_collection , art_to_art_collection
TO artnet_editor ;
GRANT USAGE ON
SEQUENCE art_id_seq , artist_id_seq , tag_tag_id_seq
TO artnet_editor ;