Mercurial > libervia-pubsub
view db/sat_pubsub_update_1_2.sql @ 430:5a0ada3b61ca
Full-Text Search implementation:
/!\ pgsql schema needs to be updated /!\
/!\ Minimal PostgreSQL required version is now 12 /!\
A new options is available to specify main language of a node. By default a `generic`
language is used (which uses the `simple` configuration in PostgreSQL). When a node owner
changes the language, the index is rebuilt accordingly. It is possible to have item
specific language for multilingual nodes (but for the moment the search is done with node
language, so the results won't be good). If an item language is explicitely set in
`item_languages`, the FTS configuration won't be affected by node FTS language setting.
Search is parsed with `websearch_to_tsquery` for now, but this parser doesn't handle
prefix matching, so it may be replaced in the future.
SetConfiguration now only updates the modified values, this avoid triggering the FTS
re-indexing on each config change. `_checkNodeExists` is not called anymore as we can
check if a row has been modified to see if the node exists, this avoid a useless query.
Item storing has been slighly improved with a useless SELECT and condition removed.
To avoid 2 schema updates in a row, the `sat_pubsub_update_5_6.sql` file also prepares the
implementation of XEP-0346 by updating nodes with a schema and creating the suitable
template nodes.
author | Goffi <goffi@goffi.org> |
---|---|
date | Fri, 11 Dec 2020 17:18:52 +0100 |
parents | 1dc606612405 |
children |
line wrap: on
line source
-- we check version of the database before doing anything -- and stop execution if not good \set ON_ERROR_STOP DO $$ DECLARE ver smallint; BEGIN SELECT value INTO ver FROM metadata WHERE key='version'; IF NOT FOUND OR ver!='1' THEN RAISE EXCEPTION 'This update file needs to be applied on database schema version 1, you use version %',ver; END IF; END$$; \unset ON_ERROR_STOP -- end of version check /* roster access model was badly used, we rename it to publisher-roster */ ALTER TABLE nodes DROP CONSTRAINT nodes_access_model_check; UPDATE nodes SET access_model = 'publisher-roster' WHERE access_model = 'roster'; ALTER TABLE nodes ADD CHECK (access_model IN ('open', 'publisher-roster', 'whitelist', 'publish-only', 'self-publisher')); ALTER TABLE items DROP CONSTRAINT items_access_model_check; UPDATE items SET access_model = 'publisher-roster' WHERE access_model = 'roster'; ALTER TABLE items ADD CHECK (access_model IN ('open', 'publisher-roster', 'whitelist')); ALTER TABLE affiliations DROP CONSTRAINT affiliations_affiliation_check; ALTER TABLE affiliations ADD CHECK (affiliation IN ('outcast', 'member', 'publisher', 'owner')); CREATE TABLE item_jids_authorized ( item_jids_authorized_id serial PRIMARY KEY, item_id integer NOT NULL references items ON DELETE CASCADE, jid text NOT NULL, UNIQUE (item_id,jid) ); CREATE TABLE item_languages ( item_languages_id serial PRIMARY KEY, item_id integer NOT NULL references items ON DELETE CASCADE, language text NOT NULL, UNIQUE (item_id,language) ); UPDATE metadata SET value='2' WHERE key='version';