From 8d5d979cba744a31c0da08173608c8b5282fb2fa Mon Sep 17 00:00:00 2001 From: "Alvar C.H. Freude" Date: Sat, 30 Mar 2024 00:45:40 +0100 Subject: [PATCH] Add old includes --- helper/10-revoke-all.sql | 9 ++++ helper/20-grant-all-read.sql | 8 +++ helper/21-grant-reader.sql | 8 +++ helper/31-grant-inserter.sql | 7 +++ helper/32-grant-inserter-read.sql | 7 +++ helper/33-grant-inserter-updater.sql | 8 +++ helper/50-function-revoke-all.sql | 10 ++++ helper/51-function-updater.sql | 8 +++ helper/52-function-inserter.sql | 8 +++ helper/53-function-reader.sql | 8 +++ helper/54-function-maintenance.sql | 8 +++ helper/80-simple-normalised.sql | 80 ++++++++++++++++++++++++++++ helper/README.md | 39 ++++++++++++++ 13 files changed, 208 insertions(+) create mode 100644 helper/10-revoke-all.sql create mode 100644 helper/20-grant-all-read.sql create mode 100644 helper/21-grant-reader.sql create mode 100644 helper/31-grant-inserter.sql create mode 100644 helper/32-grant-inserter-read.sql create mode 100644 helper/33-grant-inserter-updater.sql create mode 100644 helper/50-function-revoke-all.sql create mode 100644 helper/51-function-updater.sql create mode 100644 helper/52-function-inserter.sql create mode 100644 helper/53-function-reader.sql create mode 100644 helper/54-function-maintenance.sql create mode 100644 helper/80-simple-normalised.sql create mode 100644 helper/README.md diff --git a/helper/10-revoke-all.sql b/helper/10-revoke-all.sql new file mode 100644 index 0000000..ea3afbd --- /dev/null +++ b/helper/10-revoke-all.sql @@ -0,0 +1,9 @@ +-- +-- Revoke all from Table, set Owner +-- + +ALTER TABLE :schema.:table OWNER TO :owner; +REVOKE ALL ON :schema.:table FROM PUBLIC; +REVOKE ALL ON :schema.:table FROM current_user; + + diff --git a/helper/20-grant-all-read.sql b/helper/20-grant-all-read.sql new file mode 100644 index 0000000..30ad520 --- /dev/null +++ b/helper/20-grant-all-read.sql @@ -0,0 +1,8 @@ +-- +-- Grant read to all users +-- +-- + +\ir 10-revoke-all.sql +GRANT SELECT ON :schema.:table TO :all_users; + diff --git a/helper/21-grant-reader.sql b/helper/21-grant-reader.sql new file mode 100644 index 0000000..c07ceeb --- /dev/null +++ b/helper/21-grant-reader.sql @@ -0,0 +1,8 @@ +-- +-- Grant read to default reader +-- +-- + +\ir 10-revoke-all.sql +GRANT SELECT ON :schema.:table TO :default_reader; + diff --git a/helper/31-grant-inserter.sql b/helper/31-grant-inserter.sql new file mode 100644 index 0000000..fbe04df --- /dev/null +++ b/helper/31-grant-inserter.sql @@ -0,0 +1,7 @@ +-- +-- Grant insert to inserter +-- + +\ir 10-revoke-all.sql +GRANT INSERT ON :schema.:table TO :default_inserter; + diff --git a/helper/32-grant-inserter-read.sql b/helper/32-grant-inserter-read.sql new file mode 100644 index 0000000..428e29f --- /dev/null +++ b/helper/32-grant-inserter-read.sql @@ -0,0 +1,7 @@ +-- +-- Grant read and insert to inserter +-- + +\ir 31-grant-inserter.sql +GRANT SELECT ON :schema.:table TO :default_inserter; + diff --git a/helper/33-grant-inserter-updater.sql b/helper/33-grant-inserter-updater.sql new file mode 100644 index 0000000..b11f006 --- /dev/null +++ b/helper/33-grant-inserter-updater.sql @@ -0,0 +1,8 @@ +-- +-- Grant insert to inserter +-- + +\ir 10-revoke-all.sql +GRANT INSERT ON :schema.:table TO :default_inserter; +GRANT UPDATE ON :schema.:table TO :default_updater; + diff --git a/helper/50-function-revoke-all.sql b/helper/50-function-revoke-all.sql new file mode 100644 index 0000000..f220023 --- /dev/null +++ b/helper/50-function-revoke-all.sql @@ -0,0 +1,10 @@ +-- +-- Revoke all from function, set Owner +-- + + +ALTER FUNCTION :schema.:function OWNER TO :owner; +REVOKE ALL ON FUNCTION :schema.:function FROM PUBLIC; +REVOKE ALL ON FUNCTION :schema.:function FROM current_user; + + diff --git a/helper/51-function-updater.sql b/helper/51-function-updater.sql new file mode 100644 index 0000000..1028c8e --- /dev/null +++ b/helper/51-function-updater.sql @@ -0,0 +1,8 @@ +-- +-- Updater is allowed to call this function +-- + +\ir 50-function-revoke-all.sql + +GRANT EXECUTE ON FUNCTION :schema.:function TO :default_updater; + diff --git a/helper/52-function-inserter.sql b/helper/52-function-inserter.sql new file mode 100644 index 0000000..c8b5aa3 --- /dev/null +++ b/helper/52-function-inserter.sql @@ -0,0 +1,8 @@ +-- +-- Inserter darf die Funktion aufrufen +-- + +\ir 50-function-revoke-all.sql + +GRANT EXECUTE ON FUNCTION :schema.:function TO :default_inserter; + diff --git a/helper/53-function-reader.sql b/helper/53-function-reader.sql new file mode 100644 index 0000000..fb06cf8 --- /dev/null +++ b/helper/53-function-reader.sql @@ -0,0 +1,8 @@ +-- +-- Inserter darf die Funktion aufrufen +-- + +\ir 50-function-revoke-all.sql + +GRANT EXECUTE ON FUNCTION :schema.:function TO :default_reader; + diff --git a/helper/54-function-maintenance.sql b/helper/54-function-maintenance.sql new file mode 100644 index 0000000..642bdec --- /dev/null +++ b/helper/54-function-maintenance.sql @@ -0,0 +1,8 @@ +-- +-- Maintenance user is allowed to call this function +-- + +\ir 50-function-revoke-all.sql + +GRANT EXECUTE ON FUNCTION :schema.:function TO :default_maintenance; + diff --git a/helper/80-simple-normalised.sql b/helper/80-simple-normalised.sql new file mode 100644 index 0000000..93a82b4 --- /dev/null +++ b/helper/80-simple-normalised.sql @@ -0,0 +1,80 @@ +/* + +Creates a normalised table and insert function + +Needed variables: + + :entity_plural + :entity + +use function get_XXX_id(YYY) to get the ID of a XXX for value YYY. +The generated function is fast and reliable (race conditions!). + + +Example for entity host, hosts: + +Creates a function calles get_host_id(VARCHAR) and a table with an ID and +a "host" column. +When calling get_host_id, it returns the ID of an already existing +row with the given host or inserts a new one and returns this ID. + +For reliability get_host_id(host) has three steps: + + 1. Try to SELECT the ID, finish when found some + 2. When none found, try to INSERT a new row and return ID, finish when no conflice + 3. When conflict (concurrent insert of the same host), then again try to SELECT. + +*/ + +\set insert_function _insert_ :entity +\set get_function get_ :entity _id +\set entity_in :entity _in + + +CREATE TABLE :entity_plural + ( + id SERIAL NOT NULL PRIMARY KEY, + :entity VARCHAR NOT NULL + ); + +\set table :entity_plural +\ir 21-grant-reader.sql + +CREATE UNIQUE INDEX ON :entity_plural(:entity varchar_pattern_ops); + + + +-- only internal use: +-- insert or do nothing when already exists + +-- ugly, to trick out psql and psql variables in quoted strings ... +\set code '$CODE$ INSERT INTO ' :entity_plural ' (' :entity ') VALUES (' :entity_in ') ON CONFLICT (' :entity ') DO NOTHING RETURNING id; $CODE$' + +CREATE OR REPLACE FUNCTION :insert_function(:entity_in VARCHAR) +RETURNS INTEGER AS + :code + LANGUAGE sql + VOLATILE + RETURNS NULL ON NULL INPUT; + + +-- Select ID; or Insert; or select (because possible race condition: other process may inserted this ID in the meantime concurrently!). + +\set _select '(SELECT id FROM ' :entity_plural ' WHERE ' :entity ' = ' :entity_in ')' +\set _insert :insert_function '(' :entity_in ')' +\set code '$CODE$ SELECT COALESCE( ' :_select ', ' :_insert ', ' :_select '); $CODE$' + +CREATE OR REPLACE FUNCTION :get_function(:entity_in VARCHAR) + RETURNS INTEGER AS + :code + LANGUAGE sql + VOLATILE + RETURNS NULL ON NULL INPUT + SECURITY DEFINER + SET search_path TO :schema, pg_temp; + + +\set function get_ :entity _id(VARCHAR) +\ir 52-function-inserter.sql + + diff --git a/helper/README.md b/helper/README.md new file mode 100644 index 0000000..05e4e87 --- /dev/null +++ b/helper/README.md @@ -0,0 +1,39 @@ +# SQL-Helper-Files + +PostgreSQL helper files for psql, for include via `\ir helper/....` in SQL files. + +This helper files contains mostly command for setting permissions. + +## Documentation, Usage + +Common usage is to set some psql variables before include; some variables are usually global, others local for each call. + + +### Global variables: + + +``` +-- Name Value +-- ------------------------------------------- +\set schema my_project +\set db my_projectau + +\set user_prefix my_project + +\set owner :user_prefix _owner +\set default_reader :user_prefix _reader +\set default_updater :user_prefix _updater +\set default_inserter :user_prefix _inserter +``` + + +### Local variables + +Usually you have to set `table` or `function` to the name of the current table or function. Grant scripts include call of revoke scripts! + +``` +\set table last_created_table +\ir helper/20-grant-default-reader.sql +``` + +