Skip to content

Commit

Permalink
[#3556] populate_full_text_trigger + migration
Browse files Browse the repository at this point in the history
  • Loading branch information
wardi authored and David Read committed Aug 25, 2017
1 parent 1edd8c4 commit 83542a9
Showing 1 changed file with 39 additions and 4 deletions.
43 changes: 39 additions & 4 deletions ckanext/datastore/set_permissions.sql
Expand Up @@ -49,6 +49,7 @@ GRANT SELECT ON ALL TABLES IN SCHEMA public TO {readuser};
ALTER DEFAULT PRIVILEGES FOR USER {writeuser} IN SCHEMA public
GRANT SELECT ON TABLES TO {readuser};

-- a view for listing valid table (resource id) and view names
CREATE OR REPLACE VIEW "_table_metadata" AS
SELECT DISTINCT
substr(md5(dependee.relname || COALESCE(dependent.relname, '')), 0, 17) AS "_id",
Expand All @@ -62,11 +63,45 @@ CREATE OR REPLACE VIEW "_table_metadata" AS
LEFT OUTER JOIN pg_class AS dependent ON d.refobjid = dependent.oid
WHERE
(dependee.oid != dependent.oid OR dependent.oid IS NULL) AND
-- is a table (from pg_tables view definition)
-- or is a view (from pg_views view definition)
-- is a table (from pg_tables view definition)
-- or is a view (from pg_views view definition)
(dependee.relkind = 'r'::"char" OR dependee.relkind = 'v'::"char")
AND dependee.relnamespace = (
SELECT oid FROM pg_namespace WHERE nspname='public')
AND dependee.relnamespace = (
SELECT oid FROM pg_namespace WHERE nspname='public')
ORDER BY dependee.oid DESC;
ALTER VIEW "_table_metadata" OWNER TO {writeuser};
GRANT SELECT ON "_table_metadata" TO {readuser};

-- _full_text fields are now updated by a trigger when set to NULL
CREATE OR REPLACE FUNCTION populate_full_text_trigger() RETURNS trigger
AS $body$
BEGIN
IF NEW._full_text IS NOT NULL THEN
RETURN NEW;
END IF;
NEW._full_text := (
SELECT to_tsvector(string_agg(value, ' '))
FROM json_each_text(row_to_json(NEW.*))
WHERE key NOT LIKE '\_%');
RETURN NEW;
END;
$body$ LANGUAGE plpgsql;

-- migrate existing tables that don't have full text trigger applied
DO $body$
BEGIN
EXECUTE coalesce(
(SELECT string_agg(
'CREATE TRIGGER zfulltext BEFORE INSERT OR UPDATE ON ' ||
quote_ident(relname) || 'FOR EACH ROW EXECUTE PROCEDURE ' ||
'populate_full_text_trigger();', ' ')
FROM pg_class
LEFT OUTER JOIN pg_trigger AS t
ON t.tgrelid = relname::regclass AND t.tgname = 'zfulltext'
WHERE relkind = 'r'::"char" AND t.tgname IS NULL
AND relnamespace = (
SELECT oid FROM pg_namespace WHERE nspname='public')),
'SELECT 1;');
END;
$body$;

0 comments on commit 83542a9

Please sign in to comment.