Added first draft of versions to schema
parent
b83ea9796b
commit
fb38a1c1bf
37
README.md
37
README.md
|
@ -1,3 +1,38 @@
|
|||
# blog
|
||||
|
||||
Handles the contents of the blogging section.
|
||||
Handles the contents of the blogging section.
|
||||
|
||||
## Schema & Data Objects
|
||||
|
||||
All objects have a personal UUID ID, generated automatically by PostgreSQL.
|
||||
|
||||
### Sections
|
||||
|
||||
Sections group posts according to a common subject or some other metric by
|
||||
which they could be grouped. They can be seen as sub-blogs within the larger
|
||||
system. Each post can be part of only one section, & posts not part of a
|
||||
section will not be shown in the public UI.
|
||||
|
||||
A section has a title & optional description, along with a shortname. The
|
||||
shortname is what will be used inside URLs for routing.
|
||||
|
||||
A section can be part of the default posts list, meaning all posts created in
|
||||
this section will be shown on the homepage. The default list is an aggregated
|
||||
list containing all default sections.
|
||||
|
||||
A section can be private, meaning all posts created in this section will not be
|
||||
shown on the any public page without authentification. Furthermore, it can
|
||||
specify wether posts should have titles, or are not allowed to. This is to
|
||||
allow for creating microblogs, which do not require titles.
|
||||
|
||||
### Posts & Versions
|
||||
|
||||
A post represents a publication in a specific section. The posts table itself
|
||||
only specifies which section a post belongs to & wether or not the post is
|
||||
private. Any content of the actual post is stored a a version. A private post
|
||||
can only be seen by logged-in users with the right authorization.
|
||||
|
||||
Each version has its own publication date, with the last publication being
|
||||
shown when visiting the post. The UI however should also expose a way to show
|
||||
previous versions of the post. Each version has its own title (if allowed) &
|
||||
content. A version can be a draft. This means that the version will not be shown in the public UI, allowing the user to finish it at a later time.
|
||||
|
|
|
@ -1,7 +1,8 @@
|
|||
-- This file should undo anything in `up.sql`
|
||||
drop trigger insert_enforce_post_titles on posts;
|
||||
drop trigger update_enforce_post_titles on posts;
|
||||
drop function enforce_post_titles;
|
||||
drop trigger insert_enforce_version_titles on versions;
|
||||
drop trigger update_enforce_version_titles on versions;
|
||||
drop function enforce_version_titles;
|
||||
|
||||
drop table versions cascade;
|
||||
drop table posts cascade;
|
||||
drop table sections cascade;
|
||||
|
|
|
@ -1,4 +1,3 @@
|
|||
-- Your SQL goes here
|
||||
create table sections (
|
||||
id uuid DEFAULT gen_random_uuid() PRIMARY KEY,
|
||||
|
||||
|
@ -11,48 +10,80 @@ create table sections (
|
|||
-- 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
|
||||
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,
|
||||
|
||||
section_id uuid NOT NULL REFERENCES sections(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),
|
||||
-- Post date, defaults to today
|
||||
publish_date date NOT NULL DEFAULT now(),
|
||||
-- Content of the post
|
||||
content text NOT NULL
|
||||
-- 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 function enforce_post_titles() returns trigger as $enforce_post_titles$
|
||||
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 sections where id = new.section_id and has_titles
|
||||
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 sections where id = new.section_id and not has_titles
|
||||
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;
|
||||
$enforce_post_titles$ language plpgsql;
|
||||
$$ language plpgsql;
|
||||
|
||||
create trigger insert_enforce_post_titles
|
||||
before insert on posts
|
||||
create trigger insert_enforce_version_titles
|
||||
before insert on versions
|
||||
for each row
|
||||
execute function enforce_post_titles();
|
||||
execute function enforce_version_titles();
|
||||
|
||||
create trigger update_enforce_post_titles
|
||||
before update of title on posts
|
||||
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_post_titles();
|
||||
execute function enforce_version_titles();
|
||||
|
|
|
@ -2,9 +2,8 @@ table! {
|
|||
posts (id) {
|
||||
id -> Uuid,
|
||||
section_id -> Uuid,
|
||||
title -> Nullable<Varchar>,
|
||||
publish_date -> Date,
|
||||
content -> Text,
|
||||
is_private -> Bool,
|
||||
is_archived -> Bool,
|
||||
}
|
||||
}
|
||||
|
||||
|
@ -16,12 +15,26 @@ table! {
|
|||
description -> Nullable<Text>,
|
||||
is_default -> Bool,
|
||||
has_titles -> Bool,
|
||||
is_private -> Bool,
|
||||
}
|
||||
}
|
||||
|
||||
table! {
|
||||
versions (id) {
|
||||
id -> Uuid,
|
||||
post_id -> Uuid,
|
||||
title -> Nullable<Varchar>,
|
||||
publish_date -> Nullable<Date>,
|
||||
content -> Text,
|
||||
is_draft -> Bool,
|
||||
}
|
||||
}
|
||||
|
||||
joinable!(posts -> sections (section_id));
|
||||
joinable!(versions -> posts (post_id));
|
||||
|
||||
allow_tables_to_appear_in_same_query!(
|
||||
posts,
|
||||
sections,
|
||||
versions,
|
||||
);
|
||||
|
|
Reference in New Issue