Skip to content

Commit 4546d2f

Browse files
committed
dataset set permissions
1 parent ae8cc9a commit 4546d2f

File tree

1 file changed

+66
-4
lines changed

1 file changed

+66
-4
lines changed

set_permissions.sql

Lines changed: 66 additions & 4 deletions
Original file line numberDiff line numberDiff line change
@@ -1,20 +1,25 @@
11
/*
22
This script configures the permissions for the datastore.
3+
34
It ensures that the datastore read-only user will only be able to select from
45
the datastore database but has no create/write/edit permission or any
56
permissions on other databases. You must execute this script as a database
67
superuser on the PostgreSQL server that hosts your datastore database.
8+
79
For example, if PostgreSQL is running locally and the "postgres" user has the
810
appropriate permissions (as in the default Ubuntu PostgreSQL install), you can
911
run:
10-
paster datastore set-permissions | sudo -u postgres psql
12+
13+
ckan -c /etc/ckan/default/ckan.ini datastore set-permissions | sudo -u postgres psql
14+
1115
Or, if your PostgreSQL server is remote, you can pipe the permissions script
1216
over SSH:
13-
paster datastore set-permissions | ssh dbserver sudo -u postgres psql
17+
18+
ckan -c /etc/ckan/default/ckan.ini datastore set-permissions | ssh dbserver sudo -u postgres psql
19+
1420
*/
1521

1622
-- create the read-only user
17-
1823
DO $$
1924
BEGIN
2025
CREATE USER {readuser} WITH ENCRYPTED PASSWORD {readpassword};
@@ -39,4 +44,61 @@ GRANT SELECT ON ALL TABLES IN SCHEMA public TO {readuser};
3944

4045
-- grant access to new tables and views by default
4146
ALTER DEFAULT PRIVILEGES FOR USER {writeuser} IN SCHEMA public
42-
GRANT SELECT ON TABLES TO {readuser};
47+
GRANT SELECT ON TABLES TO {readuser};
48+
49+
-- a view for listing valid table (resource id) and view names
50+
CREATE OR REPLACE VIEW "_table_metadata" AS
51+
SELECT DISTINCT
52+
substr(md5(dependee.relname || COALESCE(dependent.relname, '')), 0, 17) AS "_id",
53+
dependee.relname AS name,
54+
dependee.oid AS oid,
55+
dependent.relname AS alias_of
56+
FROM
57+
pg_class AS dependee
58+
LEFT OUTER JOIN pg_rewrite AS r ON r.ev_class = dependee.oid
59+
LEFT OUTER JOIN pg_depend AS d ON d.objid = r.oid
60+
LEFT OUTER JOIN pg_class AS dependent ON d.refobjid = dependent.oid
61+
WHERE
62+
(dependee.oid != dependent.oid OR dependent.oid IS NULL) AND
63+
-- is a table (from pg_tables view definition)
64+
-- or is a view (from pg_views view definition)
65+
(dependee.relkind = 'r'::"char" OR dependee.relkind = 'v'::"char")
66+
AND dependee.relnamespace = (
67+
SELECT oid FROM pg_namespace WHERE nspname='public')
68+
ORDER BY dependee.oid DESC;
69+
ALTER VIEW "_table_metadata" OWNER TO {writeuser};
70+
GRANT SELECT ON "_table_metadata" TO {readuser};
71+
72+
-- _full_text fields are now updated by a trigger when set to NULL
73+
CREATE OR REPLACE FUNCTION populate_full_text_trigger() RETURNS trigger
74+
AS $body$
75+
BEGIN
76+
IF NEW._full_text IS NOT NULL THEN
77+
RETURN NEW;
78+
END IF;
79+
NEW._full_text := (
80+
SELECT to_tsvector(string_agg(value, ' '))
81+
FROM json_each_text(row_to_json(NEW.*))
82+
WHERE key NOT LIKE '\_%');
83+
RETURN NEW;
84+
END;
85+
$body$ LANGUAGE plpgsql;
86+
ALTER FUNCTION populate_full_text_trigger() OWNER TO {writeuser};
87+
88+
-- migrate existing tables that don't have full text trigger applied
89+
DO $body$
90+
BEGIN
91+
EXECUTE coalesce(
92+
(SELECT string_agg(
93+
'CREATE TRIGGER zfulltext BEFORE INSERT OR UPDATE ON ' ||
94+
quote_ident(relname) || ' FOR EACH ROW EXECUTE PROCEDURE ' ||
95+
'populate_full_text_trigger();', ' ')
96+
FROM pg_class
97+
LEFT OUTER JOIN pg_trigger AS t
98+
ON t.tgrelid = relname::regclass AND t.tgname = 'zfulltext'
99+
WHERE relkind = 'r'::"char" AND t.tgname IS NULL
100+
AND relnamespace = (
101+
SELECT oid FROM pg_namespace WHERE nspname='public')),
102+
'SELECT 1;');
103+
END;
104+
$body$;

0 commit comments

Comments
 (0)