|
| 1 | +-- complain if script is sourced in psql, rather than via CREATE EXTENSION |
| 2 | +\echo Use "CREATE EXTENSION external_file" to load this file. \quit |
| 3 | + |
| 4 | +CREATE TABLE directories ( |
| 5 | + directory_name name NOT NULL PRIMARY KEY, |
| 6 | + directory_path text NOT NULL |
| 7 | +); |
| 8 | + |
| 9 | +REVOKE ALL ON directories FROM PUBLIC; |
| 10 | +GRANT SELECT ON directories TO PUBLIC; |
| 11 | + |
| 12 | +CREATE TABLE directory_roles ( |
| 13 | + directory_name name REFERENCES directories(directory_name) ON DELETE CASCADE ON UPDATE CASCADE, |
| 14 | + directory_role name, |
| 15 | + directory_read boolean NOT NULL, |
| 16 | + directory_write boolean NOT NULL, |
| 17 | + PRIMARY KEY (directory_name,directory_role) |
| 18 | +); |
| 19 | + |
| 20 | +REVOKE ALL ON directory_roles FROM PUBLIC; |
| 21 | +GRANT SELECT ON directory_roles TO PUBLIC; |
| 22 | + |
| 23 | +-- Include tables into pg_dump |
| 24 | +SELECT pg_catalog.pg_extension_config_dump('directories', ''); |
| 25 | +SELECT pg_catalog.pg_extension_config_dump('directory_roles', ''); |
| 26 | + |
| 27 | + |
| 28 | +CREATE TYPE efile AS ( |
| 29 | + directory name, |
| 30 | + filename varchar(256) |
| 31 | +); |
| 32 | + |
| 33 | +REVOKE ALL ON TYPE efile FROM PUBLIC; |
| 34 | +GRANT USAGE ON TYPE efile TO PUBLIC; |
| 35 | + |
| 36 | + |
| 37 | +CREATE OR REPLACE FUNCTION getEfilePath(e_file efile, need_read boolean, need_write boolean) |
| 38 | + RETURNS text |
| 39 | +AS $$ |
| 40 | +DECLARE |
| 41 | + p_path text; |
| 42 | + r record; |
| 43 | + read_enable boolean := false; |
| 44 | + write_enable boolean := false; |
| 45 | +BEGIN |
| 46 | + IF coalesce(e_file.filename,'')='' THEN |
| 47 | + RAISE EXCEPTION 'Filename is empty.'; |
| 48 | + END IF; |
| 49 | + IF e_file.filename ~ '\.\.' THEN |
| 50 | + RAISE EXCEPTION 'double point (..) are forbidden inside filename'; |
| 51 | + END IF; |
| 52 | + SELECT directory_path INTO p_path FROM directories WHERE directory_name= e_file.directory; |
| 53 | + IF NOT FOUND THEN |
| 54 | + RAISE EXCEPTION 'Directory % don''t exist.',e_file.directory; |
| 55 | + END IF; |
| 56 | + FOR r IN |
| 57 | + (SELECT directory_role,directory_read,directory_write FROM directory_roles WHERE directory_name= e_file.directory) |
| 58 | + LOOP |
| 59 | + IF pg_has_role(session_user,r.directory_role,'USAGE') THEN |
| 60 | + IF r.directory_read THEN |
| 61 | + read_enable := true; |
| 62 | + END IF; |
| 63 | + IF r.directory_write THEN |
| 64 | + write_enable := true; |
| 65 | + END IF; |
| 66 | + END IF; |
| 67 | + END LOOP; |
| 68 | + IF (need_read AND NOT read_enable) OR (need_write AND NOT write_enable) THEN |
| 69 | + RAISE EXCEPTION 'Missing right for this directory: %' ,e_file.directory; |
| 70 | + END IF; |
| 71 | + p_path := p_path || e_file.filename; |
| 72 | + RETURN p_path; |
| 73 | +END; |
| 74 | +$$ |
| 75 | +LANGUAGE PLPGSQL STABLE SECURITY DEFINER SET search_path = @extschema@, pg_temp; |
| 76 | + |
| 77 | + |
| 78 | +CREATE OR REPLACE FUNCTION writeEfile(buffer bytea, e_file efile) |
| 79 | + RETURNS void |
| 80 | +AS $$ |
| 81 | +DECLARE |
| 82 | + l_oid oid; |
| 83 | + lfd integer; |
| 84 | + lsize integer; |
| 85 | +BEGIN |
| 86 | + l_oid := lo_create(0); |
| 87 | + lfd := lo_open(l_oid,131072); --0x00020000 write mode |
| 88 | + lsize := lowrite(lfd,buffer); |
| 89 | + PERFORM lo_close(lfd); |
| 90 | + PERFORM lo_export(l_oid,getEfilePath(e_file,false,true)); |
| 91 | + PERFORM lo_unlink(l_oid); |
| 92 | +END; |
| 93 | +$$ LANGUAGE PLPGSQL SECURITY DEFINER SET search_path = @extschema@, pg_temp; |
| 94 | + |
| 95 | + |
| 96 | +CREATE OR REPLACE FUNCTION readEfile(e_file efile, p_result OUT bytea) |
| 97 | +AS $$ |
| 98 | +DECLARE |
| 99 | + l_oid oid; |
| 100 | +BEGIN |
| 101 | + SELECT lo_import(getEfilePath(e_file,true,false)) INTO l_oid; |
| 102 | + SELECT string_agg (data, NULL::bytea ORDER BY pageno) INTO p_result FROM pg_largeobject WHERE loid = l_oid; |
| 103 | + PERFORM lo_unlink(l_oid); |
| 104 | +END; |
| 105 | +$$ |
| 106 | +LANGUAGE PLPGSQL SECURITY DEFINER SET search_path = @extschema@, pg_temp; |
| 107 | + |
| 108 | + |
| 109 | +CREATE OR REPLACE FUNCTION copyEfile(src efile, dest efile) |
| 110 | + RETURNS void |
| 111 | +AS $$ |
| 112 | +DECLARE |
| 113 | + l_oid oid; |
| 114 | +BEGIN |
| 115 | + SELECT lo_import(getEfilePath(src,true,false)) INTO l_oid; |
| 116 | + PERFORM lo_export(l_oid,getEfilePath(dest,false,true)); |
| 117 | + PERFORM lo_unlink(l_oid); |
| 118 | +END; |
| 119 | +$$ |
| 120 | +LANGUAGE PLPGSQL SECURITY DEFINER SET search_path = @extschema@, pg_temp; |
| 121 | + |
| 122 | +CREATE OR REPLACE FUNCTION efile_check_role() |
| 123 | + RETURNS trigger |
| 124 | +AS $$ |
| 125 | +BEGIN |
| 126 | + PERFORM * from pg_roles where rolname = NEW.directory_role; |
| 127 | + IF NOT FOUND THEN |
| 128 | + RAISE EXCEPTION 'role % must exists', NEW.directory_role; |
| 129 | + RETURN NULL; |
| 130 | + END IF; |
| 131 | + RETURN NEW; |
| 132 | +END; |
| 133 | +$$ |
| 134 | +LANGUAGE PLPGSQL; |
| 135 | + |
| 136 | +CREATE TRIGGER trg_efile_check_role |
| 137 | + BEFORE UPDATE OR INSERT ON directory_roles |
| 138 | + FOR EACH ROW |
| 139 | + EXECUTE PROCEDURE efile_check_role(); |
| 140 | + |
| 141 | + |
| 142 | +-- Function used to replace Oracle BFILENAME that returns efile |
| 143 | +CREATE OR REPLACE FUNCTION efilename(directory name, filename varchar(256)) RETURNS efile |
| 144 | +AS 'SELECT ($1, $2)::efile;' |
| 145 | +LANGUAGE SQL STRICT; |
| 146 | + |
0 commit comments