This repository has been archived on 2023-07-04. You can view files and clone it, but cannot push or open issues/pull-requests.
blog/migrations/2021-09-13-143540_sections/up.sql

90 lines
3.0 KiB
PL/PgSQL

create table sections (
id uuid DEFAULT gen_random_uuid() PRIMARY KEY,
-- Title of the section
title varchar(255) UNIQUE NOT NULL,
-- Name to use when routing (this just makes for prettier URLs)
shortname varchar(32) UNIQUE NOT NULL,
-- Optional description of the section
description text,
-- Wether to show the section in the default list on the homepage
is_default boolean NOT NULL DEFAULT false,
-- Wether the posts should contain titles or not
has_titles boolean NOT NULL DEFAULT true,
-- Wether posts in this section should be shown publicly
is_private boolean NOT NULL DEFAULT false
);
create table posts (
id uuid DEFAULT gen_random_uuid() PRIMARY KEY,
-- Posts shouldn't get deleted when we delete a section, as they're the
-- most valuable part of a blog
section_id uuid NOT NULL REFERENCES sections(id) ON DELETE SET NULL,
-- Wether a post should be private
is_private boolean NOT NULL DEFAULT false,
-- Wether the post is archived
is_archived boolean NOT NULL DEFAULT false
);
create table versions (
id uuid DEFAULT gen_random_uuid() PRIMARY KEY,
-- A version should be deleted when its referenced post is deleted
post_id uuid NOT NULL REFERENCES posts(id) ON DELETE CASCADE,
-- Title of the post. Wether this is NULL or not is enforced using the
-- enforce_post_titles trigger.
title varchar(255),
-- Publish date
publish_date date,
-- Content of the post, in Markdown
content text NOT NULL DEFAULT '',
-- Wether the version is still a draft
is_draft boolean NOT NULL default true,
-- This check allows draft posts to be created without having to enter a
-- publish date, but forces them to have one if they're not a draft.
CHECK (is_draft OR publish_date IS NOT NULL)
);
create function enforce_version_titles() returns trigger as $$
begin
-- Draft versions shouldn't be evaluated.
if new.is_draft then
return new;
end if;
-- Check for a wrongfully null title
if new.title is null and exists (
select 1 from posts
inner join sections on posts.section_id = sections.id
where posts.id = new.post_id and sections.has_titles
) then
raise exception 'Expected a post title, but got null.';
end if;
if new.title is not null and exists (
select 1 from posts
inner join sections on posts.section_id = sections.id
where posts.id = new.post_id and not sections.has_titles
) then
raise exception 'Expected an empty post title, but got a value.';
end if;
return new;
end;
$$ language plpgsql;
create trigger insert_enforce_version_titles
before insert on versions
for each row
execute function enforce_version_titles();
create trigger update_enforce_version_titles
before update of title on versions
for each row
when (old.title is distinct from new.title)
execute function enforce_version_titles();