Files
readeck/internal/db/migrations/postgres/schema.sql
Olivier Meunier 822d78d57d TOTP authentication
This is only the first part. When a totp_secret exists for a user, the
authentication then asks for the code and carries on.

The totp lib can handle 6 or 8 letter codes and sha1, sha256 and sha512.
For maximum compatibility with Google Authenticator though, it sticks
to 6 character and sha1.
2025-12-09 07:23:13 +01:00

197 lines
6.9 KiB
PL/PgSQL

-- SPDX-FileCopyrightText: © 2021 Olivier Meunier <olivier@neokraft.net>
--
-- SPDX-License-Identifier: AGPL-3.0-only
CREATE TABLE migration (
id integer PRIMARY KEY,
name varchar(128) NOT NULL,
applied timestamptz NOT NULL
);
CREATE TABLE IF NOT EXISTS "user" (
id SERIAL PRIMARY KEY,
uid varchar(32) UNIQUE NOT NULL,
created timestamptz NOT NULL,
updated timestamptz NOT NULL,
username varchar(128) UNIQUE NOT NULL,
email varchar(128) UNIQUE NOT NULL,
password varchar(256) NOT NULL,
"group" varchar(64) NOT NULL DEFAULT 'user',
settings jsonb NOT NULL DEFAULT '{}',
seed integer NOT NULL DEFAULT 0,
totp_secret bytea NULL
);
CREATE TABLE IF NOT EXISTS token (
id SERIAL PRIMARY KEY,
uid varchar(32) UNIQUE NOT NULL,
user_id integer NOT NULL,
created timestamptz NOT NULL,
last_used timestamptz NULL,
expires timestamptz NULL,
is_enabled boolean NOT NULL DEFAULT true,
application varchar(128) NOT NULL,
roles jsonb NOT NULL DEFAULT '[]',
client_info jsonb NULL,
CONSTRAINT fk_token_user FOREIGN KEY (user_id) REFERENCES "user"(id) ON DELETE CASCADE
);
CREATE TABLE IF NOT EXISTS "credential" (
id SERIAL PRIMARY KEY,
uid varchar(32) UNIQUE NOT NULL,
user_id integer NOT NULL,
created timestamptz NOT NULL,
last_used timestamptz NULL,
is_enabled boolean NOT NULL DEFAULT true,
name varchar(128) NOT NULL,
password varchar(256) NOT NULL,
roles jsonb NOT NULL DEFAULT '[]',
CONSTRAINT fk_app_password_user FOREIGN KEY (user_id) REFERENCES "user"(id) ON DELETE CASCADE
);
CREATE TABLE IF NOT EXISTS bookmark (
id SERIAL PRIMARY KEY,
uid varchar(32) UNIQUE NOT NULL,
user_id integer NOT NULL,
created timestamptz NOT NULL,
updated timestamptz NOT NULL,
is_marked boolean NOT NULL DEFAULT false,
is_archived boolean NOT NULL DEFAULT false,
state integer NOT NULL DEFAULT 0,
url text NOT NULL,
initial_url text NOT NULL,
domain text NOT NULL,
title text NOT NULL,
site text NOT NULL DEFAULT '',
site_name text NOT NULL DEFAULT '',
published timestamptz,
authors jsonb NOT NULL DEFAULT '[]',
lang varchar(16) NOT NULL DEFAULT '',
dir varchar(3) NOT NULL DEFAULT '',
type varchar(64) NOT NULL DEFAULT '',
description text NOT NULL DEFAULT '',
"text" text NOT NULL DEFAULT '',
word_count integer NOT NULL DEFAULT 0,
duration integer NOT NULL DEFAULT 0,
embed text NOT NULL DEFAULT '',
file_path text NOT NULL DEFAULT '',
files jsonb NOT NULL DEFAULT '[]',
errors jsonb NOT NULL DEFAULT '[]',
labels jsonb NOT NULL DEFAULT '[]',
read_progress smallint NOT NULL DEFAULT 0,
read_anchor text NOT NULL DEFAULT '',
annotations jsonb NOT NULL DEFAULT '[]',
links jsonb NOT NULL DEFAULT '[]',
CONSTRAINT fk_bookmark_user FOREIGN KEY (user_id) REFERENCES "user"(id) ON DELETE CASCADE
);
CREATE INDEX bookmark_created_idx ON "bookmark" USING btree (created DESC);
CREATE INDEX bookmark_updated_idx ON "bookmark" USING btree (updated DESC);
CREATE INDEX bookmark_url_idx ON "bookmark" (url);
CREATE INDEX bookmark_initial_url_idx ON "bookmark" (initial_url);
CREATE TABLE IF NOT EXISTS bookmark_removed (
uid varchar(32) NOT NULL,
user_id integer NOT NULL,
deleted timestamptz NOT NULL DEFAULT NOW(),
CONSTRAINT fk_bookmark_removed_user FOREIGN KEY (user_id) REFERENCES "user"(id) ON DELETE CASCADE
);
CREATE INDEX bookmark_removed_deleted_idx ON "bookmark_removed" (deleted DESC);
--
-- Search configuration
--
CREATE EXTENSION IF NOT EXISTS unaccent;
CREATE TEXT SEARCH CONFIGURATION ts (COPY = simple);
ALTER TEXT SEARCH CONFIGURATION ts
ALTER MAPPING FOR hword, hword_part, word, host
WITH unaccent, english_stem, french_stem;
CREATE TABLE bookmark_search (
bookmark_id int4 NOT NULL PRIMARY KEY,
title tsvector NULL,
description tsvector NULL,
"text" tsvector NULL,
site tsvector NULL,
author tsvector NULL,
"label" tsvector NULL,
CONSTRAINT fk_bookmark_search_bookmark FOREIGN KEY (bookmark_id) REFERENCES bookmark(id) ON DELETE CASCADE
);
CREATE INDEX bookmark_search_all_idx ON bookmark_search USING GIN((title || description || "text" || site || "label"));
CREATE INDEX bookmark_search_title_idx ON bookmark_search USING GIN (title);
CREATE INDEX bookmark_search_site_idx ON bookmark_search USING GIN (site);
CREATE INDEX bookmark_search_author_idx ON bookmark_search USING GIN (author);
CREATE INDEX bookmark_search_label_idx ON bookmark_search USING GIN (label);
CREATE OR REPLACE FUNCTION bookmark_search_update()
RETURNS trigger
LANGUAGE plpgsql
AS $$
BEGIN
DELETE FROM bookmark_search WHERE bookmark_id = OLD.id;
IF tg_op = 'UPDATE' OR tg_op = 'INSERT' THEN
INSERT INTO bookmark_search (
bookmark_id, title, description, "text", site, author, "label"
) VALUES (
NEW.id,
setweight(to_tsvector('ts', NEW.title), 'A'),
to_tsvector('ts', NEW.description),
to_tsvector('ts', NEW."text"),
to_tsvector('ts',
NEW.site_name || ' ' || NEW.domain || ' ' ||
REGEXP_REPLACE(NEW.site, '^www\.', '') || ' ' ||
REPLACE(NEW.domain, '.', ' ') ||
REPLACE(REGEXP_REPLACE(NEW.site, '^www\.', ''), '.', ' ')
),
jsonb_to_tsvector('ts', NEW.authors, '["string"]'),
setweight(jsonb_to_tsvector('ts', NEW.labels, '["string"]'), 'A')
);
END IF;
RETURN NEW;
END;
$$;
CREATE TRIGGER bookmark_tsu AFTER INSERT OR UPDATE ON bookmark
FOR EACH ROW EXECUTE PROCEDURE bookmark_search_update();
CREATE OR REPLACE FUNCTION bookmark_after_delete()
RETURNS trigger
LANGUAGE plpgsql
AS $$
BEGIN
INSERT INTO bookmark_removed (
uid, user_id
) VALUES (
OLD.uid, OLD.user_id
);
RETURN OLD;
END;
$$;
CREATE TRIGGER bookmark_ad AFTER DELETE on bookmark
FOR EACH ROW EXECUTE PROCEDURE bookmark_after_delete();
CREATE TABLE IF NOT EXISTS bookmark_collection (
id SERIAL PRIMARY KEY,
uid varchar(32) UNIQUE NOT NULL,
user_id integer NOT NULL,
created timestamptz NOT NULL,
updated timestamptz NOT NULL,
name text NOT NULL,
is_pinned boolean NOT NULL DEFAULT false,
filters json NOT NULL DEFAULT '{}',
CONSTRAINT fk_bookmark_collection_user FOREIGN KEY (user_id) REFERENCES "user"(id) ON DELETE CASCADE
);