cordis/server/sql/init.sql
2021-12-04 06:02:11 -06:00

192 lines
6.6 KiB
PL/PgSQL

--
-- Should be run from a fresh postgres install on the postgres root user
--
\c postgres
DROP DATABASE IF EXISTS "cordis";
DROP USER IF EXISTS "cordis";
CREATE USER "cordis" WITH PASSWORD 'cordis_pass';
CREATE DATABASE "cordis" WITH ENCODING 'UTF8' OWNER 'cordis';
\c cordis
CREATE EXTENSION IF NOT EXISTS "uuid-ossp"; -- for uuid_generate_v4()
CREATE EXTENSION IF NOT EXISTS "pgcrypto"; -- for digest(data, 'sha256')
--
-- corDis Schema
--
-- NOTE: members will be for specific guilds and NOT global to all guilds hosted by the server
CREATE TABLE "guilds" (
"id" UUID NOT NULL DEFAULT uuid_generate_v4()
, PRIMARY KEY ("id")
);
ALTER TABLE "guilds" OWNER TO "cordis";
CREATE TABLE "resources" (
"id" UUID NOT NULL DEFAULT uuid_generate_v4()
, "guild_id" UUID NOT NULL REFERENCES "guilds"("id")
, "hash" BYTEA NOT NULL
, "data" BYTEA NOT NULL
, PRIMARY KEY ("id")
, UNIQUE ("guild_id", "hash")
);
ALTER TABLE "resources" OWNER TO "cordis";
CREATE TABLE "guilds_meta" (
"id" UUID NOT NULL REFERENCES "guilds"("id")
, "name" VARCHAR(64) NOT NULL
, "icon_resource_id" UUID NOT NULL REFERENCES "resources"("id")
, PRIMARY KEY ("id")
);
ALTER TABLE "guilds_meta" OWNER TO "cordis";
CREATE TYPE "member_status_t" AS ENUM (
'offline',
'online',
'away',
'busy',
'invisible'
);
CREATE TABLE "members" (
"id" UUID NOT NULL DEFAULT uuid_generate_v4()
, "guild_id" UUID NOT NULL REFERENCES "guilds"("id")
, "public_key" BYTEA NOT NULL
, "display_name" VARCHAR(64) NOT NULL
, "status" member_status_t DEFAULT 'offline'
, "avatar_resource_id" UUID NOT NULL REFERENCES "resources"("id")
, PRIMARY KEY ("id")
, UNIQUE ("public_key")
);
ALTER TABLE "members" OWNER TO "cordis";
CREATE OR REPLACE FUNCTION "get_public_status"("status" member_status_t) RETURNS member_status_t AS $$
DECLARE
BEGIN
IF "status"='invisible' THEN
"status":='offline';
END IF;
RETURN "status";
END;
$$ LANGUAGE plpgsql;
CREATE TABLE "tokens" (
"id" UUID NOT NULL DEFAULT uuid_generate_v4()
, "guild_id" UUID NOT NULL REFERENCES "guilds"("id")
, "expires" TIMESTAMP WITH TIME ZONE NOT NULL
, "token" UUID NOT NULL DEFAULT uuid_generate_v4()
, "member_id" UUID REFERENCES "members"("id")
, "created" TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW()
, PRIMARY KEY ("id")
, UNIQUE ("guild_id", "token")
);
ALTER TABLE "tokens" OWNER TO "cordis";
CREATE TABLE "channels" (
"id" UUID NOT NULL DEFAULT uuid_generate_v4()
, "guild_id" UUID NOT NULL REFERENCES "guilds"("id")
, "index" INTEGER NOT NULL
, "name" VARCHAR(64) NOT NULL
, "flavor_text" VARCHAR(256)
, PRIMARY KEY ("id")
, UNIQUE ("guild_id", "index")
);
ALTER TABLE "channels" OWNER TO "cordis";
-- TODO: Maybe use varchar for message text to prevent oversized messages?
-- NOTE: this will probably all be handled in node.js code instead (for more configurability).
CREATE TABLE "messages" (
"id" UUID NOT NULL-- DEFAULT uuid_generate_v4() -- Removed since this is manually generated for ordering purposes
, "guild_id" UUID NOT NULL REFERENCES "guilds"("id") ON DELETE CASCADE
, "channel_id" UUID NOT NULL REFERENCES "channels"("id") ON DELETE CASCADE
, "member_id" UUID NOT NULL REFERENCES "members"("id") -- probably want set null
, "sent_dtg" TIMESTAMP WITH TIME ZONE NOT NULL
, "text" TEXT
, "resource_id" UUID REFERENCES "resources"("id")
, "resource_name" VARCHAR(256)
, "resource_width" INT
, "resource_height" INT
, "resource_preview_id" UUID REFERENCES "resources"("id")
, "order" TEXT
, PRIMARY KEY ("id")
);
ALTER TABLE "messages" OWNER TO "cordis";
CREATE TABLE "roles" (
"id" UUID NOT NULL DEFAULT uuid_generate_v4()
, "guild_id" UUID NOT NULL REFERENCES "guilds"("id")
, "name" TEXT NOT NULL
, "color" TEXT NOT NULL
, "priority" INTEGER NOT NULL DEFAULT 0 -- for figuring out which color
, PRIMARY KEY ("id")
, UNIQUE ("guild_id", "priority")
);
ALTER TABLE "roles" OWNER TO "cordis";
CREATE TYPE "privilege_t" AS ENUM (
'modify_profile'
, 'modify_channels'
, 'modify_members'
);
CREATE TABLE "role_privileges" (
"role_id" UUID NOT NULL REFERENCES "roles"("id") ON DELETE CASCADE
, "guild_id" UUID NOT NULL REFERENCES "guilds"("id")
, "privilege" privilege_t NOT NULL
);
ALTER TABLE "role_privileges" OWNER TO "cordis";
CREATE TABLE "member_roles" (
"member_id" UUID NOT NULL REFERENCES "members"("id")
, "role_id" UUID NOT NULL REFERENCES "roles"("id") ON DELETE CASCADE
, "guild_id" UUID NOT NULL REFERENCES "guilds"("id")
, UNIQUE ("member_id", "role_id", "guild_id")
);
ALTER TABLE "member_roles" OWNER TO "cordis";
CREATE OR REPLACE VIEW "members_with_roles" AS (
SELECT
"members"."id" AS id
, "guilds"."id" AS guild_id
, "members"."display_name" AS display_name
, get_public_status("members"."status") AS status
, "members"."avatar_resource_id" AS avatar_resource_id
, "priority_role"."name" AS role_name
, "priority_role"."color" AS role_color
, "priority_role"."priority" AS role_priority
, STRING_AGG(DISTINCT "role_privileges"."privilege"::text, ',') AS privileges
FROM
"members"
JOIN "guilds" ON "members"."guild_id"="guilds"."id"
LEFT JOIN "member_roles" ON
"members"."id"="member_roles"."member_id"
AND "member_roles"."guild_id"="members"."guild_id"
LEFT JOIN "roles" AS priority_role ON
priority_role."id"="member_roles"."role_id"
AND priority_role."guild_id"="member_roles"."guild_id"
LEFT JOIN "roles" AS all_roles ON
all_roles."id"="member_roles"."role_id"
AND all_roles."guild_id"="member_roles"."guild_id"
LEFT JOIN "role_privileges" ON
"role_privileges"."role_id"=all_roles."id"
AND "role_privileges"."guild_id"=all_roles."guild_id"
WHERE
priority_role."priority" IS NULL
OR priority_role."priority"=(
SELECT MAX("roles"."priority")
FROM "roles", "member_roles"
WHERE
"roles"."id"="member_roles"."role_id"
AND "roles"."guild_id"="member_roles"."guild_id"
AND "member_roles"."member_id"="members"."id"
)
GROUP BY
"members"."id"
, "guilds"."id"
, "priority_role"."id"
);
ALTER VIEW "members_with_roles" OWNER TO "cordis";