-- vim:set tw=0: CREATE TABLE machines ( machine SERIAL PRIMARY KEY, machinename VARCHAR NOT NULL, UNIQUE ( machinename ) ); CREATE TABLE countries ( country SERIAL PRIMARY KEY, countryname VARCHAR NOT NULL, UNIQUE ( countryname ) ); CREATE TABLE songs ( song SERIAL PRIMARY KEY, title VARCHAR NOT NULL, artist VARCHAR NOT NULL, minbpm INTEGER NOT NULL, maxbpm INTEGER NOT NULL, UNIQUE ( title ) ); CREATE TABLE machinesongs ( song INTEGER NOT NULL REFERENCES songs, machine INTEGER NOT NULL REFERENCES machines, PRIMARY KEY ( song, machine ) ); CREATE TABLE scoringsystems ( scoringsystem SERIAL PRIMARY KEY, scoringsystemname VARCHAR NOT NULL, UNIQUE ( scoringsystemname ) ); CREATE TABLE songratings ( song INTEGER NOT NULL REFERENCES songs, -- strictly song+machine playmode VARCHAR NOT NULL CHECK (playmode IN ('single','double')), difficulty VARCHAR NOT NULL CHECK (difficulty IN ('beginner','standard','difficult','expert','challenge')), feetrating INTEGER NOT NULL CHECK (feetrating >= 0 AND feetrating <= 10), PRIMARY KEY (song, playmode, difficulty) ); CREATE TABLE players ( player SERIAL PRIMARY KEY, nick VARCHAR NOT NULL, UNIQUE ( nick ) ); CREATE TABLE seasons ( season SERIAL PRIMARY KEY, seasonname VARCHAR NOT NULL, UNIQUE ( seasonname ) ); CREATE TABLE tournaments ( tournament SERIAL PRIMARY KEY, season INTEGER NOT NULL REFERENCES seasons, tournamentname VARCHAR NOT NULL, country INTEGER NOT NULL REFERENCES countries, location VARCHAR NOT NULL, "date" DATE NOT NULL, machine INTEGER NOT NULL REFERENCES machines, scoringsystem INTEGER NOT NULL REFERENCES scoringsystems, UNIQUE ( season, tournamentname ) ); CREATE TABLE tournamentparticipation ( tournament INTEGER NOT NULL REFERENCES tournaments, player INTEGER NOT NULL REFERENCES players, paid BOOLEAN NOT NULL, PRIMARY KEY ( tournament, player ) ); CREATE TABLE tournamentrankings ( tournament INTEGER NOT NULL REFERENCES tournaments, ranking INTEGER NOT NULL, player INTEGER NOT NULL REFERENCES players, points INTEGER, UNIQUE (tournament, player), PRIMARY KEY (tournament, ranking) ); CREATE TABLE rounds ( tournament INTEGER NOT NULL REFERENCES tournaments, round INTEGER NOT NULL, randomsongs INTEGER NOT NULL, chosensongs INTEGER NOT NULL, numqualifying INTEGER, PRIMARY KEY (tournament, round) ); CREATE TABLE groups ( tournament INTEGER NOT NULL REFERENCES tournaments, round INTEGER NOT NULL, parallel INTEGER NOT NULL, FOREIGN KEY (tournament, round) REFERENCES rounds (tournament, round), PRIMARY KEY (tournament, round, parallel) ); CREATE TABLE roundrandomsongs ( tournament INTEGER NOT NULL, round INTEGER NOT NULL, parallel INTEGER NOT NULL, song INTEGER NOT NULL REFERENCES songs, FOREIGN KEY (tournament, round, parallel) REFERENCES groups (tournament, round, parallel), PRIMARY KEY (tournament, round, parallel, song) ); CREATE TABLE roundparticipation ( tournament INTEGER NOT NULL, round INTEGER NOT NULL, parallel INTEGER NOT NULL, player INTEGER NOT NULL REFERENCES players, position INTEGER NOT NULL, UNIQUE (tournament, round, player), UNIQUE (tournament, round, parallel, position), FOREIGN KEY (tournament, round, parallel) REFERENCES groups (tournament, round, parallel), PRIMARY KEY (tournament, round, parallel, player) ); CREATE TABLE scores ( tournament INTEGER NOT NULL, round INTEGER NOT NULL, parallel INTEGER NOT NULL, player INTEGER NOT NULL REFERENCES players, songnumber INTEGER NOT NULL, song INTEGER REFERENCES songs, playmode VARCHAR CHECK (playmode IS NULL OR playmode IN ('single','double')), difficulty VARCHAR CHECK (difficulty IS NULL OR difficulty IN ('beginner','standard','difficult','expert','challenge')), chosen BOOLEAN, score INTEGER CHECK (score IS NULL OR (score >= 0 AND score <= 10000)), FOREIGN KEY (song, playmode, difficulty) REFERENCES songratings (song, playmode, difficulty), FOREIGN KEY (tournament, round, parallel, player) REFERENCES roundparticipation (tournament, round, parallel, player), PRIMARY KEY (tournament, round, parallel, player, songnumber) ); CREATE TABLE randomsongsused ( song INTEGER NOT NULL PRIMARY KEY REFERENCES songs );