Create tables, indexes, functions and triggers programatically
This commit is contained in:
parent
cc12981a50
commit
c9b967a2ef
7 changed files with 154 additions and 163 deletions
142
createdb.sql
142
createdb.sql
|
@ -1,142 +0,0 @@
|
|||
--CREATE EXTENSION pg_trgm;
|
||||
|
||||
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
|
||||
);
|
||||
|
||||
-- Books column indexes
|
||||
CREATE INDEX CONCURRENTLY books_lang_idx ON books (lang);
|
||||
CREATE INDEX CONCURRENTLY books_isbn_idx ON books (isbn);
|
||||
CREATE INDEX CONCURRENTLY books_active_idx ON books (active);
|
||||
|
||||
-- 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();
|
||||
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;
|
||||
|
||||
|
||||
CREATE TABLE news (
|
||||
id serial unique,
|
||||
date timestamp,
|
||||
text text
|
||||
);
|
||||
|
||||
|
||||
CREATE TABLE users (
|
||||
id serial unique,
|
||||
username varchar(255) unique,
|
||||
password bytea,
|
||||
salt bytea,
|
||||
role varchar(255)
|
||||
);
|
||||
|
||||
|
||||
CREATE TABLE visits (
|
||||
id serial unique,
|
||||
downloads integer,
|
||||
views integer,
|
||||
book_id varchar(16) unique REFERENCES books(id) ON DELETE CASCADE
|
||||
);
|
||||
CREATE INDEX CONCURRENTLY visits_downloads_idx on visits(downloads DESC NULLS LAST);
|
||||
CREATE INDEX CONCURRENTLY visits_views_idx on visits(views DESC NULLS LAST);
|
||||
|
||||
|
||||
CREATE TABLE submissions (
|
||||
id serial unique,
|
||||
submission_id varchar(16),
|
||||
filename text,
|
||||
status text,
|
||||
book_id varchar(16) unique REFERENCES books(id) ON DELETE SET NULL
|
||||
);
|
||||
CREATE INDEX CONCURRENTLY submissions_id_idx on submissions(submission_id);
|
||||
CREATE INDEX CONCURRENTLY submissions_book_idx on submissions(book_id);
|
|
@ -9,7 +9,7 @@ import (
|
|||
|
||||
// Book metadata
|
||||
type Book struct {
|
||||
ID string
|
||||
ID string `sql:"type:varchar(16)"`
|
||||
Title string
|
||||
Authors []string `sql:"authors" pg:",array"`
|
||||
Contributor string
|
||||
|
@ -17,13 +17,13 @@ type Book struct {
|
|||
Description string
|
||||
Tags []string `sql:"tags" pg:",array"`
|
||||
Date string
|
||||
Lang string
|
||||
Isbn string
|
||||
FileSize int
|
||||
Cover bool `sql:",notnull"`
|
||||
Active bool `sql:",notnull"`
|
||||
UploadDate time.Time
|
||||
Tsv string
|
||||
Lang string `sql:"type:varchar(3)"`
|
||||
Isbn string `sql:"type:varchar(13)"`
|
||||
FileSize int `sql:"type:integer"`
|
||||
Cover bool `sql:",notnull"`
|
||||
Active bool `sql:",notnull"`
|
||||
UploadDate time.Time `sql:"type:timestamp"`
|
||||
Tsv string `sql:"type:tsvector"`
|
||||
Visit *Visit
|
||||
}
|
||||
|
||||
|
|
|
@ -4,6 +4,7 @@ import (
|
|||
"time"
|
||||
|
||||
"github.com/go-pg/pg"
|
||||
"github.com/go-pg/pg/orm"
|
||||
)
|
||||
|
||||
type DB interface {
|
||||
|
@ -72,10 +73,14 @@ func Init(options Options) (DB, error) {
|
|||
Password: options.Password,
|
||||
Database: options.Name,
|
||||
})
|
||||
// TODO: create db
|
||||
|
||||
var db pgDB
|
||||
db.sql = sql
|
||||
|
||||
err := db.create()
|
||||
if err != nil {
|
||||
return nil, err
|
||||
}
|
||||
go db.frontPageUpdater()
|
||||
|
||||
return &db, nil
|
||||
|
@ -86,6 +91,134 @@ func (db pgDB) Close() error {
|
|||
return db.sql.Close()
|
||||
}
|
||||
|
||||
func (db pgDB) create() error {
|
||||
models := []interface{}{&Book{}, &New{}, &user{}, &Visit{}, &Submission{}}
|
||||
for _, model := range models {
|
||||
options := &orm.CreateTableOptions{
|
||||
IfNotExists: true,
|
||||
FKConstraints: true,
|
||||
}
|
||||
switch model.(type) {
|
||||
case *Submission:
|
||||
// XXX: ON DELETE SET NULL contraint is not supported
|
||||
options.FKConstraints = false
|
||||
}
|
||||
err := db.sql.CreateTable(model, options)
|
||||
if err != nil {
|
||||
return err
|
||||
}
|
||||
}
|
||||
|
||||
_, err := db.sql.Exec(createSQL)
|
||||
if err != nil {
|
||||
return err
|
||||
}
|
||||
return nil
|
||||
}
|
||||
|
||||
func RO(db DB) DB {
|
||||
return &roDB{db}
|
||||
}
|
||||
|
||||
const createSQL = `
|
||||
-- Books column indexes
|
||||
CREATE INDEX IF NOT EXISTS books_lang_idx ON books (lang);
|
||||
CREATE INDEX IF NOT EXISTS books_isbn_idx ON books (isbn);
|
||||
CREATE INDEX IF NOT EXISTS books_active_idx ON books (active);
|
||||
|
||||
-- Books trigram indexes
|
||||
CREATE INDEX IF NOT EXISTS books_title_idx ON books USING GIN (title gin_trgm_ops);
|
||||
CREATE INDEX IF NOT EXISTS books_contributor_idx ON books USING GIN (contributor gin_trgm_ops);
|
||||
CREATE INDEX IF NOT EXISTS books_publisher_idx ON books USING GIN (publisher gin_trgm_ops);
|
||||
CREATE OR REPLACE FUNCTION text(text[]) RETURNS text immutable AS $$
|
||||
select $1::text
|
||||
$$ language sql;
|
||||
CREATE INDEX IF NOT EXISTS books_authors_idx ON books USING GIN (text(authors) gin_trgm_ops);
|
||||
CREATE INDEX IF NOT EXISTS books_tags_idx ON books USING GIN (text(tags) gin_trgm_ops);
|
||||
|
||||
-- Books text search index
|
||||
CREATE OR REPLACE 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;
|
||||
DROP TRIGGER IF EXISTS tsvectorupdate ON books;
|
||||
CREATE TRIGGER tsvectorupdate BEFORE INSERT OR UPDATE
|
||||
ON books FOR EACH ROW EXECUTE PROCEDURE books_trigger();
|
||||
CREATE INDEX IF NOT EXISTS books_idx ON books USING GIN (tsv);
|
||||
CREATE OR REPLACE 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;
|
||||
|
||||
-- Visits indexes
|
||||
CREATE INDEX IF NOT EXISTS visits_downloads_idx on visits(downloads DESC NULLS LAST);
|
||||
CREATE INDEX IF NOT EXISTS visits_views_idx on visits(views DESC NULLS LAST);
|
||||
|
||||
-- Submissions indexes
|
||||
CREATE INDEX IF NOT EXISTS submissions_id_idx on submissions(submission_id);
|
||||
CREATE INDEX IF NOT EXISTS submissions_book_idx on submissions(book_id);
|
||||
|
||||
-- Submissions constraint
|
||||
ALTER TABLE ONLY submissions
|
||||
DROP CONSTRAINT IF EXISTS submissions_book_id_fkey;
|
||||
ALTER TABLE ONLY submissions
|
||||
ADD CONSTRAINT submissions_book_id_fkey FOREIGN KEY (book_id) REFERENCES books(id) ON DELETE SET NULL;
|
||||
`
|
||||
|
|
|
@ -7,8 +7,8 @@ import (
|
|||
|
||||
// New entry in the news table
|
||||
type New struct {
|
||||
ID int
|
||||
Date time.Time
|
||||
ID int `sql:"type:serial"`
|
||||
Date time.Time `sql:"type:timestamp"`
|
||||
Text string
|
||||
}
|
||||
|
||||
|
|
|
@ -7,10 +7,10 @@ import (
|
|||
)
|
||||
|
||||
type Visit struct {
|
||||
ID int
|
||||
Downloads int `sql:",notnull"`
|
||||
Views int `sql:",notnull"`
|
||||
BookID string
|
||||
ID int `sql:"type:serial"`
|
||||
Downloads int `sql:"type:integer,notnull"`
|
||||
Views int `sql:"type:integer,notnull"`
|
||||
BookID string `sql:"type:varchar(16),unique"`
|
||||
Book *Book
|
||||
}
|
||||
|
||||
|
|
|
@ -1,11 +1,11 @@
|
|||
package database
|
||||
|
||||
type Submission struct {
|
||||
ID int
|
||||
SubmissionID string
|
||||
ID int `sql:"type:serial"`
|
||||
SubmissionID string `sql:"type:varchar(16)"`
|
||||
Filename string
|
||||
Status string
|
||||
BookID string
|
||||
BookID string `sql:"type:varchar(16),unique"`
|
||||
Book *Book
|
||||
}
|
||||
|
||||
|
|
|
@ -11,11 +11,11 @@ import (
|
|||
)
|
||||
|
||||
type user struct {
|
||||
ID int
|
||||
Username string
|
||||
ID int `sql:"type:serial"`
|
||||
Username string `sql:"type:varchar(255),unique"`
|
||||
Password []byte
|
||||
Salt []byte
|
||||
Role string
|
||||
Role string `sql:"type:varchar(255)"`
|
||||
}
|
||||
|
||||
func (db *pgDB) AddUser(name string, pass string) error {
|
||||
|
|
Reference in a new issue