changeset 5323:eec88a166251 extented-report

Added report_reciever column to user_profiles table.
author Sascha L. Teichmann <sascha.teichmann@intevation.de>
date Sat, 29 May 2021 17:19:03 +0200
parents 80d9fd782f00
children 348d91848278
files schema/gemma.sql schema/updates/1450/01.report_reciever.sql schema/version.sql
diffstat 3 files changed, 106 insertions(+), 3 deletions(-) [+]
line wrap: on
line diff
--- a/schema/gemma.sql	Thu May 27 15:09:13 2021 +0200
+++ b/schema/gemma.sql	Sat May 29 17:19:03 2021 +0200
@@ -384,7 +384,8 @@
         -- keep username length compatible with role identifier
         country char(2) NOT NULL REFERENCES countries,
         map_extent box2d NOT NULL,
-        email_address varchar NOT NULL
+        email_address varchar NOT NULL,
+        report_reciever boolean NOT NULL DEFAULT false
     )
 ;
 
@@ -492,7 +493,8 @@
             CAST('' AS varchar) AS pw,
             p.country,
             p.map_extent,
-            p.email_address
+            p.email_address,
+            p.report_reciever
         FROM internal.user_profiles p
             JOIN pg_roles u ON p.username = u.rolname
             JOIN pg_auth_members a ON u.oid = a.member
--- /dev/null	Thu Jan 01 00:00:00 1970 +0000
+++ b/schema/updates/1450/01.report_reciever.sql	Sat May 29 17:19:03 2021 +0200
@@ -0,0 +1,101 @@
+ALTER TABLE internal.user_profiles
+  ADD COLUMN report_reciever boolean NOT NULL DEFAULT false;
+
+CREATE OR REPLACE VIEW list_users WITH (security_barrier) AS
+    SELECT
+        r.rolname,
+        p.username,
+        CAST('' AS varchar) AS pw,
+        p.country,
+        p.map_extent,
+        p.email_address,
+        p.report_reciever
+    FROM internal.user_profiles p
+        JOIN pg_roles u ON p.username = u.rolname
+        JOIN pg_auth_members a ON u.oid = a.member
+        JOIN pg_roles r ON a.roleid = r.oid
+    WHERE p.username = current_user
+        OR pg_has_role('waterway_admin', 'MEMBER')
+            AND p.country = (
+                SELECT country FROM internal.user_profiles
+                    WHERE username = current_user)
+            AND r.rolname <> 'sys_admin'
+        OR pg_has_role('sys_admin', 'MEMBER')
+;
+
+CREATE OR REPLACE FUNCTION internal.update_user() RETURNS trigger
+AS $$
+DECLARE
+    cur_username varchar;
+BEGIN
+    cur_username = OLD.username;
+
+    IF NEW.username <> cur_username
+    THEN
+        EXECUTE format(
+            'ALTER ROLE %I RENAME TO %I', cur_username, NEW.username);
+        cur_username = NEW.username;
+    END IF;
+
+    UPDATE internal.user_profiles p
+        SET (username, country, map_extent, email_address, report_reciever)
+        = (NEW.username, NEW.country, NEW.map_extent, NEW.email_address, NEW.report_reciever)
+        WHERE p.username = cur_username;
+
+    IF NEW.rolname <> OLD.rolname
+    THEN
+        EXECUTE format(
+            'REVOKE %I FROM %I', OLD.rolname, cur_username);
+        EXECUTE format(
+            'GRANT %I TO %I', NEW.rolname, cur_username);
+    END IF;
+
+    IF NEW.pw IS NOT NULL AND NEW.pw <> ''
+    THEN
+        EXECUTE format(
+            'ALTER ROLE %I PASSWORD %L',
+            cur_username,
+            internal.check_password(NEW.pw));
+    END IF;
+
+    -- Do not leak new password
+    NEW.pw = '';
+    RETURN NEW;
+END;
+$$
+    LANGUAGE plpgsql
+    SECURITY DEFINER;
+
+CREATE OR REPLACE FUNCTION internal.create_user() RETURNS trigger
+AS $$
+BEGIN
+    IF NEW.map_extent IS NULL
+    THEN
+        NEW.map_extent = ST_Extent(CAST(area AS geometry))
+            FROM users.stretches st
+                JOIN users.stretch_countries stc ON stc.stretch_id = st.id
+            WHERE stc.country = NEW.country;
+    END IF;
+
+    IF NEW.username IS NOT NULL
+    -- otherwise let the constraint on user_profiles speak
+    THEN
+        EXECUTE format(
+            'CREATE ROLE %I IN ROLE %I LOGIN PASSWORD %L',
+            NEW.username,
+            NEW.rolname,
+            internal.check_password(NEW.pw));
+    END IF;
+
+    INSERT INTO internal.user_profiles (
+        username, country, map_extent, email_address, report_reciever)
+        VALUES (NEW.username, NEW.country, NEW.map_extent, NEW.email_address, NEW.report_reciever);
+
+    -- Do not leak new password
+    NEW.pw = '';
+    RETURN NEW;
+END;
+$$
+    LANGUAGE plpgsql
+    SECURITY DEFINER;
+
--- a/schema/version.sql	Thu May 27 15:09:13 2021 +0200
+++ b/schema/version.sql	Sat May 29 17:19:03 2021 +0200
@@ -1,1 +1,1 @@
-INSERT INTO gemma_schema_version(version) VALUES (1439);
+INSERT INTO gemma_schema_version(version) VALUES (1450);