This repository has been archived on 2025-03-01. You can view files and clone it, but cannot push or open issues or pull requests.
trantor/createdb.sql

123 lines
3.6 KiB
MySQL
Raw Normal View History

2017-05-18 22:16:16 +00:00
--CREATE EXTENSION pg_trgm;
2017-03-23 11:13:39 +00:00
CREATE TABLE books (
id varchar(16) primary key,
title text,
authors text[],
contributor text,
publisher text,
description text,
tags text[],
date text,
lang varchar(3),
isbn varchar(13),
file_size integer,
cover boolean,
active boolean,
upload_date timestamp,
tsv tsvector
);
2017-03-23 11:13:39 +00:00
-- Books column indexes
CREATE INDEX CONCURRENTLY books_lang_idx ON books (lang);
CREATE INDEX CONCURRENTLY books_isbn_idx ON books (isbn);
2017-05-18 22:16:16 +00:00
CREATE INDEX CONCURRENTLY books_active_idx ON books (active);
2017-03-23 11:13:39 +00:00
-- Books trigram indexes
CREATE INDEX CONCURRENTLY books_title_idx ON books USING GIN (title gin_trgm_ops);
CREATE INDEX CONCURRENTLY books_contributor_idx ON books USING GIN (contributor gin_trgm_ops);
CREATE INDEX CONCURRENTLY books_publisher_idx ON books USING GIN (publisher gin_trgm_ops);
CREATE FUNCTION text(text[]) RETURNS text immutable AS $$
select $1::text
$$ language sql;
CREATE INDEX CONCURRENTLY books_authors_idx ON books USING GIN (text(authors) gin_trgm_ops);
CREATE INDEX CONCURRENTLY books_tags_idx ON books USING GIN (text(tags) gin_trgm_ops);
-- Books text search index
CREATE FUNCTION books_trigger() RETURNS trigger AS $$
declare
lang_config regconfig;
begin
lang_config := 'simple';
if new.lang = 'da' then
lang_config := 'danish';
elsif new.lang = 'nl' then
lang_config := 'dutch';
elsif new.lang = 'en' then
lang_config := 'english';
elsif new.lang = 'fi' then
lang_config := 'finnish';
elsif new.lang = 'fr' then
lang_config := 'french';
elsif new.lang = 'de' then
lang_config :='german';
elsif new.lang = 'hu' then
lang_config :='hungarian';
elsif new.lang = 'it' then
lang_config :='italian';
elsif new.lang = 'no' then
lang_config :='norwegian';
elsif new.lang = 'pt' then
lang_config :='portuguese';
elsif new.lang = 'ro' then
lang_config :='romanian';
elsif new.lang = 'ru' then
lang_config :='russian';
elsif new.lang = 'es' then
lang_config :='spanish';
elsif new.lang = 'sv' then
lang_config :='swedish';
elsif new.lang = 'tr' then
lang_config :='turkish';
end if;
new.tsv :=
setweight(to_tsvector(lang_config, coalesce(new.title,'')), 'A') ||
setweight(to_tsvector('simple', coalesce(array_to_string(new.authors, ' '),'')), 'A') ||
setweight(to_tsvector('simple', coalesce(new.contributor,'')), 'B') ||
setweight(to_tsvector('simple', coalesce(new.publisher,'')), 'B') ||
setweight(to_tsvector(lang_config, coalesce(array_to_string(new.tags, ' '),'')), 'C') ||
setweight(to_tsvector(lang_config, coalesce(new.description,'')), 'D');
return new;
end
$$ LANGUAGE plpgsql;
CREATE TRIGGER tsvectorupdate BEFORE INSERT OR UPDATE
ON books FOR EACH ROW EXECUTE PROCEDURE books_trigger();
2017-03-23 11:13:39 +00:00
CREATE INDEX CONCURRENTLY books_idx ON books USING GIN (tsv);
CREATE FUNCTION to_tsquery_multilingual(text) RETURNS tsquery AS $$
SELECT
to_tsquery('simple', $1) ||
to_tsquery('danish', $1) ||
to_tsquery('dutch', $1) ||
to_tsquery('english', $1) ||
to_tsquery('finnish', $1) ||
to_tsquery('french', $1) ||
to_tsquery('german', $1) ||
to_tsquery('hungarian', $1) ||
to_tsquery('italian', $1) ||
to_tsquery('norwegian', $1) ||
to_tsquery('portuguese', $1) ||
to_tsquery('romanian', $1) ||
to_tsquery('russian', $1) ||
to_tsquery('spanish', $1) ||
to_tsquery('swedish', $1) ||
to_tsquery('turkish', $1)
$$ LANGUAGE sql IMMUTABLE;
2016-09-04 12:32:58 -04:00
CREATE TABLE news (
id serial unique,
2016-09-04 12:32:58 -04:00
date timestamp,
text text
);
2016-09-04 12:32:58 -04:00
CREATE TABLE users (
id serial unique,
username varchar(255) unique,
password bytea,
salt bytea,
role varchar(255)
);