|
|
@ -1,5 +1,36 @@
|
|
|
|
BEGIN TRANSACTION;
|
|
|
|
BEGIN TRANSACTION;
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
-- <bktree/sql/init.sql>
|
|
|
|
|
|
|
|
-- CREATE EXTENSION bktree; -- only superuser can
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
-- Check whether any of our opclasses fail amvalidate
|
|
|
|
|
|
|
|
SELECT amname, opcname
|
|
|
|
|
|
|
|
FROM pg_opclass opc LEFT JOIN pg_am am ON am.oid = opcmethod
|
|
|
|
|
|
|
|
WHERE opc.oid >= 16384 AND NOT amvalidate(opc.oid);
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
-- </bktree/sql/init.sql>
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS sites CASCADE;
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS boards CASCADE;
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS threads CASCADE;
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS posts CASCADE;
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS attachments CASCADE;
|
|
|
|
|
|
|
|
DROP FUNCTION IF EXISTS update_post_body_search_index;
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
-- It won't let us drop roles otherwise and the IFs are to keep this script idempotent.
|
|
|
|
|
|
|
|
DO
|
|
|
|
|
|
|
|
$$BEGIN
|
|
|
|
|
|
|
|
IF EXISTS (SELECT FROM pg_roles WHERE rolname = 'chan_archiver') THEN
|
|
|
|
|
|
|
|
EXECUTE 'REVOKE ALL PRIVILEGES ON DATABASE chan_archives FROM chan_archiver';
|
|
|
|
|
|
|
|
END IF;
|
|
|
|
|
|
|
|
IF EXISTS (SELECT FROM pg_roles WHERE rolname = 'chan_archive_anon') THEN
|
|
|
|
|
|
|
|
EXECUTE 'REVOKE ALL PRIVILEGES ON DATABASE chan_archives FROM chan_archive_anon';
|
|
|
|
|
|
|
|
END IF;
|
|
|
|
|
|
|
|
END$$;
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
DROP ROLE IF EXISTS chan_archiver;
|
|
|
|
|
|
|
|
DROP ROLE IF EXISTS chan_archive_anon;
|
|
|
|
|
|
|
|
|
|
|
|
CREATE TABLE IF NOT EXISTS sites
|
|
|
|
CREATE TABLE IF NOT EXISTS sites
|
|
|
|
( site_id serial primary key
|
|
|
|
( site_id serial primary key
|
|
|
|
, name text NOT NULL
|
|
|
|
, name text NOT NULL
|
|
|
@ -16,20 +47,27 @@ CREATE TABLE IF NOT EXISTS boards
|
|
|
|
|
|
|
|
|
|
|
|
CREATE TABLE IF NOT EXISTS threads
|
|
|
|
CREATE TABLE IF NOT EXISTS threads
|
|
|
|
( thread_id bigserial primary key
|
|
|
|
( thread_id bigserial primary key
|
|
|
|
|
|
|
|
, board_thread_id bigint NOT NULL
|
|
|
|
, creation_time timestamp with time zone NOT NULL
|
|
|
|
, creation_time timestamp with time zone NOT NULL
|
|
|
|
, board_id int NOT NULL
|
|
|
|
, board_id int NOT NULL
|
|
|
|
, CONSTRAINT board_fk FOREIGN KEY (board_id) REFERENCES boards (board_id) ON DELETE CASCADE
|
|
|
|
, CONSTRAINT board_fk FOREIGN KEY (board_id) REFERENCES boards (board_id) ON DELETE CASCADE
|
|
|
|
|
|
|
|
, CONSTRAINT unique_board_board_thread_id_constraint UNIQUE (board_id, board_thread_id)
|
|
|
|
);
|
|
|
|
);
|
|
|
|
|
|
|
|
CREATE INDEX threads_board_id_idx ON threads (board_id);
|
|
|
|
|
|
|
|
|
|
|
|
CREATE TABLE IF NOT EXISTS posts
|
|
|
|
CREATE TABLE IF NOT EXISTS posts
|
|
|
|
( post_id bigserial primary key
|
|
|
|
( post_id bigserial primary key
|
|
|
|
|
|
|
|
, board_post_id bigint NOT NULL
|
|
|
|
, creation_time timestamp with time zone NOT NULL
|
|
|
|
, creation_time timestamp with time zone NOT NULL
|
|
|
|
, body text
|
|
|
|
, body text
|
|
|
|
, body_search_index tsvector
|
|
|
|
, body_search_index tsvector
|
|
|
|
, thread_id bigint NOT NULL
|
|
|
|
, thread_id bigint NOT NULL
|
|
|
|
|
|
|
|
, CONSTRAINT unique_thread_board_id_constraint UNIQUE (thread_id, board_post_id)
|
|
|
|
, CONSTRAINT thread_fk FOREIGN KEY (thread_id) REFERENCES threads (thread_id) ON DELETE CASCADE
|
|
|
|
, CONSTRAINT thread_fk FOREIGN KEY (thread_id) REFERENCES threads (thread_id) ON DELETE CASCADE
|
|
|
|
);
|
|
|
|
);
|
|
|
|
CREATE INDEX post_body_search_idx ON posts USING GIN (body_search_index);
|
|
|
|
CREATE INDEX posts_body_search_idx ON posts USING GIN (body_search_index);
|
|
|
|
|
|
|
|
CREATE INDEX posts_thread_id_idx ON posts (thread_id);
|
|
|
|
|
|
|
|
CREATE INDEX posts_board_post_id_idx ON posts (board_post_id);
|
|
|
|
|
|
|
|
|
|
|
|
CREATE OR REPLACE FUNCTION update_post_body_search_index() RETURNS trigger AS $$
|
|
|
|
CREATE OR REPLACE FUNCTION update_post_body_search_index() RETURNS trigger AS $$
|
|
|
|
BEGIN
|
|
|
|
BEGIN
|
|
|
@ -44,4 +82,44 @@ ON posts
|
|
|
|
FOR EACH ROW
|
|
|
|
FOR EACH ROW
|
|
|
|
EXECUTE FUNCTION update_post_body_search_index();
|
|
|
|
EXECUTE FUNCTION update_post_body_search_index();
|
|
|
|
|
|
|
|
|
|
|
|
ROLLBACK;
|
|
|
|
CREATE TABLE IF NOT EXISTS attachments
|
|
|
|
|
|
|
|
( attachment_id bigserial primary key
|
|
|
|
|
|
|
|
, mimetype text NOT NULL
|
|
|
|
|
|
|
|
, creation_time timestamp with time zone NOT NULL
|
|
|
|
|
|
|
|
, md5_hash text NOT NULL
|
|
|
|
|
|
|
|
, phash bigint
|
|
|
|
|
|
|
|
, illegal boolean NOT NULL DEFAULT false
|
|
|
|
|
|
|
|
, post_id bigint NOT NULL
|
|
|
|
|
|
|
|
, CHECK
|
|
|
|
|
|
|
|
(
|
|
|
|
|
|
|
|
(mimetype NOT IN ('image/jpeg', 'image/png', 'image/gif'))
|
|
|
|
|
|
|
|
OR
|
|
|
|
|
|
|
|
(phash IS NOT NULL)
|
|
|
|
|
|
|
|
)
|
|
|
|
|
|
|
|
, CONSTRAINT post_fk FOREIGN KEY (post_id) REFERENCES posts (post_id) ON DELETE CASCADE
|
|
|
|
|
|
|
|
);
|
|
|
|
|
|
|
|
CREATE INDEX attachments_post_id_idx ON attachments (post_id);
|
|
|
|
|
|
|
|
CREATE INDEX attachments_md5_hash_idx ON attachments (md5_hash);
|
|
|
|
|
|
|
|
CREATE INDEX attachments_phash_bktree_index ON attachments USING spgist (phash bktree_ops);
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
CREATE ROLE chan_archive_anon nologin;
|
|
|
|
|
|
|
|
GRANT CONNECT ON DATABASE chan_archives TO chan_archive_anon;
|
|
|
|
|
|
|
|
GRANT SELECT ON sites TO chan_archive_anon;
|
|
|
|
|
|
|
|
GRANT SELECT ON boards TO chan_archive_anon;
|
|
|
|
|
|
|
|
GRANT SELECT ON threads TO chan_archive_anon;
|
|
|
|
|
|
|
|
GRANT SELECT ON posts TO chan_archive_anon;
|
|
|
|
|
|
|
|
GRANT SELECT ON attachments TO chan_archive_anon;
|
|
|
|
|
|
|
|
GRANT chan_archive_anon TO admin;
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
CREATE ROLE chan_archiver noinherit login password 'test_password';
|
|
|
|
|
|
|
|
GRANT CONNECT ON DATABASE chan_archives TO chan_archiver;
|
|
|
|
|
|
|
|
GRANT chan_archive_anon TO chan_archiver;
|
|
|
|
|
|
|
|
GRANT ALL ON sites TO chan_archiver;
|
|
|
|
|
|
|
|
GRANT ALL ON boards TO chan_archiver;
|
|
|
|
|
|
|
|
GRANT ALL ON threads TO chan_archiver;
|
|
|
|
|
|
|
|
GRANT ALL ON posts TO chan_archiver;
|
|
|
|
|
|
|
|
GRANT ALL ON attachments TO chan_archiver;
|
|
|
|
|
|
|
|
GRANT EXECUTE ON FUNCTION update_post_body_search_index TO chan_archiver;
|
|
|
|
|
|
|
|
GRANT chan_archiver TO admin;
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
COMMIT;
|
|
|
|