Skip to content

Commit b010347

Browse files
committed
Change unauthorized characters to .. instead of / and \ to support
subfolders in filename. Thanks to duursma for the report. Create new version files.
1 parent 56c68ce commit b010347

File tree

5 files changed

+210
-2
lines changed

5 files changed

+210
-2
lines changed

README.external_file

Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1 @@
1+
README.md

external_file--1.1.sql

Lines changed: 8 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -96,9 +96,16 @@ CREATE OR REPLACE FUNCTION readEfile(e_file efile, p_result OUT bytea)
9696
AS $$
9797
DECLARE
9898
l_oid oid;
99+
r record;
99100
BEGIN
101+
p_result := '';
100102
SELECT lo_import(getEfilePath(e_file,true,false)) INTO l_oid;
101-
SELECT string_agg (data, NULL::bytea ORDER BY pageno) INTO p_result FROM pg_largeobject WHERE loid = l_oid;
103+
FOR r IN ( SELECT data
104+
FROM pg_largeobject
105+
WHERE loid = l_oid
106+
ORDER BY pageno ) LOOP
107+
p_result = p_result || r.data;
108+
END LOOP;
102109
PERFORM lo_unlink(l_oid);
103110
END;
104111
$$

external_file--1.2.sql

Lines changed: 146 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,146 @@
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+

external_file.control

Lines changed: 1 addition & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -1,5 +1,5 @@
11
comment = 'functions to read or write files from postgresql server filesystems'
2-
default_version = '1.1'
2+
default_version = '1.2'
33
encoding = 'utf8'
44
relocatable = false
55
superuser = true
Lines changed: 54 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,54 @@
1+
-- complain if script is sourced in psql, rather than via CREATE EXTENSION
2+
\echo Use "ALTER EXTENSION external_file UPDATE TO \"1.2\";" to load this file. \quit
3+
4+
CREATE OR REPLACE FUNCTION readEfile(e_file efile, p_result OUT bytea)
5+
AS $$
6+
DECLARE
7+
l_oid oid;
8+
BEGIN
9+
SELECT lo_import(getEfilePath(e_file,true,false)) INTO l_oid;
10+
SELECT string_agg (data, NULL::bytea ORDER BY pageno) INTO p_result FROM pg_largeobject WHERE loid = l_oid;
11+
PERFORM lo_unlink(l_oid);
12+
END;
13+
$$
14+
LANGUAGE PLPGSQL SECURITY DEFINER SET search_path = @extschema@, pg_temp;
15+
16+
CREATE OR REPLACE FUNCTION getEfilePath(e_file efile, need_read boolean, need_write boolean)
17+
RETURNS text
18+
AS $$
19+
DECLARE
20+
p_path text;
21+
r record;
22+
read_enable boolean := false;
23+
write_enable boolean := false;
24+
BEGIN
25+
IF coalesce(e_file.filename,'')='' THEN
26+
RAISE EXCEPTION 'Filename is empty.';
27+
END IF;
28+
IF e_file.filename ~ '\.\.' THEN
29+
RAISE EXCEPTION 'double point (..) are forbidden inside filename';
30+
END IF;
31+
SELECT directory_path INTO p_path FROM directories WHERE directory_name= e_file.directory;
32+
IF NOT FOUND THEN
33+
RAISE EXCEPTION 'Directory % don''t exist.',e_file.directory;
34+
END IF;
35+
FOR r IN
36+
(SELECT directory_role,directory_read,directory_write FROM directory_roles WHERE directory_name= e_file.directory)
37+
LOOP
38+
IF pg_has_role(session_user,r.directory_role,'USAGE') THEN
39+
IF r.directory_read THEN
40+
read_enable := true;
41+
END IF;
42+
IF r.directory_write THEN
43+
write_enable := true;
44+
END IF;
45+
END IF;
46+
END LOOP;
47+
IF (need_read AND NOT read_enable) OR (need_write AND NOT write_enable) THEN
48+
RAISE EXCEPTION 'Missing right for this directory: %' ,e_file.directory;
49+
END IF;
50+
p_path := p_path || e_file.filename;
51+
RETURN p_path;
52+
END;
53+
$$
54+
LANGUAGE PLPGSQL STABLE SECURITY DEFINER SET search_path = @extschema@, pg_temp;

0 commit comments

Comments
 (0)