Skip to content

Commit

Permalink
Updated psql model included end-instruction marks (--#)
Browse files Browse the repository at this point in the history
  • Loading branch information
Javinator9889 committed May 17, 2020
1 parent d36a248 commit 73a3841
Showing 1 changed file with 30 additions and 2 deletions.
32 changes: 30 additions & 2 deletions Design/Database/psql_model.sql
Original file line number Diff line number Diff line change
@@ -1,21 +1,29 @@
-- PostgreSQL model for YouTubeMDBot application
-- Created by Javinator9889 - thu, 24 October, 2019
-- Last modification: Sat, 29 February, 2020
-- Version 1.2
-- Last modification: Sun, 17 May, 2020
-- Version 1.3

-- DROP schema - only for testing
DROP SCHEMA IF EXISTS youtubemd CASCADE;
--#
DROP TYPE IF EXISTS AFORMAT;
--#
DROP TYPE IF EXISTS aquality;
--#
DROP TYPE IF EXISTS behaviour;
--#

-- Custom "enum" types
CREATE TYPE AFORMAT AS ENUM ('mp3', 'm4a', 'ogg');
--#
CREATE TYPE AQUALITY AS ENUM ('128k', '96k');
--#
CREATE TYPE BEHAVIOUR AS ENUM ('always', 'not_found', 'ask', 'never');
--#

-- Create DB schema
CREATE SCHEMA IF NOT EXISTS youtubemd;
--#

-- ---------------------------------------
-- Table User --
Expand All @@ -28,6 +36,7 @@ CREATE TABLE IF NOT EXISTS youtubemd.User
"lang" VARCHAR(2),
"first_access" date
);
--#

-- ---------------------------------------------
-- Table Preferences --
Expand All @@ -46,6 +55,7 @@ CREATE TABLE IF NOT EXISTS youtubemd.Preferences
ON DELETE CASCADE
ON UPDATE CASCADE
);
--#

-- ------------------------------------------
-- Table YouTube --
Expand All @@ -56,6 +66,7 @@ CREATE TABLE IF NOT EXISTS youtubemd.YouTube
"times_requested" INT NOT NULL DEFAULT 0,
PRIMARY KEY ("id")
);
--#

-- ------------------------------------------
-- Table Metadata --
Expand All @@ -73,6 +84,7 @@ CREATE TABLE IF NOT EXISTS youtubemd.Metadata
"custom_metadata" BOOLEAN,
PRIMARY KEY ("id")
);
--#

-- ----------------------------------------------------
-- Relation between YouTube and Metadata --
Expand All @@ -89,6 +101,7 @@ CREATE TABLE IF NOT EXISTS youtubemd.Video_Has_Metadata
FOREIGN KEY ("metadata_id")
REFERENCES youtubemd.Metadata ("id")
);
--#

-- --------------------------------------
-- Table File --
Expand All @@ -104,6 +117,7 @@ CREATE TABLE IF NOT EXISTS youtubemd.File
FOREIGN KEY ("metadata_id")
REFERENCES youtubemd.Metadata ("id")
);
--#

-- -----------------------------------------
-- Table History --
Expand All @@ -128,6 +142,7 @@ CREATE TABLE IF NOT EXISTS youtubemd.History
FOREIGN KEY ("metadata_id")
REFERENCES youtubemd.Metadata ("id")
);
--#

-- ------------------------------------------
-- Table Playlist --
Expand All @@ -137,6 +152,7 @@ CREATE TABLE IF NOT EXISTS youtubemd.Playlist
"id" VARCHAR(22) NOT NULL UNIQUE,
PRIMARY KEY ("id")
);
--#

-- ----------------------------------------------
-- Table YouTube stats --
Expand All @@ -152,11 +168,15 @@ CREATE TABLE IF NOT EXISTS youtubemd.YouTubeStats
FOREIGN KEY ("id")
REFERENCES youtubemd.YouTube ("id")
);
--#

-- Additional indexes
CREATE INDEX user_preferences_idx ON youtubemd.Preferences ("user_id");
--#
CREATE INDEX video_metadata_idx ON youtubemd.Video_Has_Metadata ("id", "metadata_id");
--#
CREATE INDEX history_idx ON youtubemd.History ("id", "file_id", "user_id", "metadata_id");
--#

-- Trigger that updates different stats
CREATE FUNCTION youtubemd.process_stats() RETURNS trigger AS
Expand Down Expand Up @@ -187,6 +207,7 @@ BEGIN
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
--#

-- Complementary functions with useful operations
CREATE FUNCTION youtubemd.top_10_daily()
Expand All @@ -204,6 +225,7 @@ BEGIN
FETCH FIRST 10 ROWS ONLY;
END;
$$ LANGUAGE plpgsql;
--#

CREATE FUNCTION youtubemd.top_10_weekly()
RETURNS TABLE
Expand All @@ -220,6 +242,7 @@ BEGIN
FETCH FIRST 10 ROWS ONLY;
END;
$$ LANGUAGE plpgsql;
--#

CREATE FUNCTION youtubemd.top_10_monthly()
RETURNS TABLE
Expand All @@ -236,31 +259,36 @@ BEGIN
FETCH FIRST 10 ROWS ONLY;
END;
$$ LANGUAGE plpgsql;
--#

CREATE FUNCTION youtubemd.clear_daily_stats() RETURNS VOID AS
$$
BEGIN
UPDATE youtubemd.YouTubeStats SET daily_requests = 0;
END;
$$ LANGUAGE plpgsql;
--#

CREATE FUNCTION youtubemd.clear_weekly_stats() RETURNS VOID AS
$$
BEGIN
UPDATE youtubemd.YouTubeStats SET weekly_requests = 0;
END;
$$ LANGUAGE plpgsql;
--#

CREATE FUNCTION youtubemd.clear_monthly_stats() RETURNS VOID AS
$$
BEGIN
UPDATE youtubemd.YouTubeStats SET monthly_requests = 0;
END;
$$ LANGUAGE plpgsql;
--#

-- Init the trigger
CREATE TRIGGER stats_update
AFTER INSERT OR UPDATE
ON youtubemd.YouTube
FOR EACH ROW
EXECUTE PROCEDURE youtubemd.process_stats();
--#

0 comments on commit 73a3841

Please sign in to comment.