|
| 1 | +External file access extension |
| 2 | +============================== |
| 3 | + |
| 4 | +Allow access to "external files" from PostgreSQL server file systems. |
| 5 | +This extension is only a "secure version" of the server side lo_* functions. |
| 6 | + |
| 7 | +1. Installation requirements |
| 8 | +============================ |
| 9 | +PostgreSQL 9.1 or better are required. |
| 10 | +User with PostgreSQL superuser role for creating extension. |
| 11 | + |
| 12 | +2. Installation |
| 13 | +=============== |
| 14 | +external_file has been written as a PostgreSQL extension and uses the Extension |
| 15 | +Building Infrastructure "PGXS". |
| 16 | + |
| 17 | +You will need PostgreSQL headers and PGXS installed (if your PostgreSQL was |
| 18 | +installed with packages, install the development package). |
| 19 | + |
| 20 | +Get/Unpack the source code in a fresh directory Then the software installation |
| 21 | +should be as simple as |
| 22 | + |
| 23 | + $ make (In these version do nothing) |
| 24 | + $ make install |
| 25 | + |
| 26 | +To install the extension in a database, connect as superuser and |
| 27 | + |
| 28 | + CREATE EXTENSION external_file; |
| 29 | + |
| 30 | +By default all objects of the extension are created in the external_file schema. |
| 31 | +If you want to change the schema name you must edit the external_file.control |
| 32 | +file. Note that this schema must not be writable by normal user to not allow |
| 33 | +bypassing of the search path set with the security definer. |
| 34 | + |
| 35 | + |
| 36 | +When using schema with extension, it's better to include this schema in the |
| 37 | +default search_path. For example: |
| 38 | + |
| 39 | + ALTER DATABASE <mydb> SET search_path="$user",public,external_file; |
| 40 | + |
| 41 | +Also you can restrict USAGE grant on external_file schema to specific user and |
| 42 | +change the default search path at user level too. |
| 43 | + |
| 44 | + GRANT USAGE ON SCHEMA external_file TO <username>; |
| 45 | + |
| 46 | +Please refer to the PostgreSQL documentation for more information. |
| 47 | + |
| 48 | + |
| 49 | +3. Usage |
| 50 | +======== |
| 51 | +External file are accessed using two values, an alias for the path of the |
| 52 | +directory where the file is, and the file name. |
| 53 | + |
| 54 | +So, first, alias must be defined for the path. This definition is performed |
| 55 | +using the "directories" table. For security reason, only superuser can insert, |
| 56 | +update, delete directory definition. It's possible, with GRANT command, to |
| 57 | +change this but it's NOT recommended. |
| 58 | + |
| 59 | +Example: |
| 60 | + |
| 61 | + INSERT INTO directories(directory_name,directory_path) VALUES ('temporary','/tmp/'); |
| 62 | + |
| 63 | +ATTENTION: |
| 64 | + * the path must use the terminal separator! |
| 65 | + * the system user running PostgreSQL server (generally postgres) must have the |
| 66 | + system rights to read and/or write files |
| 67 | + * the filename don't include any / or \ character for security reason |
| 68 | + |
| 69 | +Second, rights for user and/or role are defined using the "directory_access" |
| 70 | +table. |
| 71 | + |
| 72 | +Example: |
| 73 | + |
| 74 | + INSERT INTO directory_roles(directory_name,directory_role,directory_read,directory_write) VALUES ('temporary','a_role',true,false); |
| 75 | + |
| 76 | +Now standard user can use external files. |
| 77 | + |
| 78 | +Example: |
| 79 | + |
| 80 | + -- Store a new external file blahblah.txt into the directory |
| 81 | + SELECT writeEfile('\x48656c6c6f2c0a0a596f75206172652072656164696e67206120746578742066696c652e0a0a526567617264732c0a', ('temporary', 'blahblah.txt')); |
| 82 | + |
| 83 | + ls -la /tmp/blahblah.txt |
| 84 | + -rw-r--r-- 1 postgres postgres 47 janv. 22 19:16 /tmp/blahblah.txt |
| 85 | + |
| 86 | + -- Create a table taht will use external files |
| 87 | + CREATE TABLE efile_test ( id smallint primary key, the_file efile); |
| 88 | + -- Insert a row to access the external file called blahblah.txt |
| 89 | + INSERT INTO efile_test VALUES (1,('temporary','blahblah.txt')); |
| 90 | + -- Assuming user has right to read, and the file exists |
| 91 | + SELECT id, readefile(the_file) FROM efile_test; |
| 92 | + -- Make a physical copy of the external file assuming user has right to read AND write |
| 93 | + SELECT copyefile(('temporary','blahblah.txt'),('temporary','copy_blahblah.txt')); |
| 94 | + INSERT INTO efile_test VALUES (2,('temporary','copy_blahblah.txt')); |
| 95 | + |
| 96 | + ls /tmp/*blahblah.txt |
| 97 | + -rw-r--r-- 1 postgres postgres 47 janv. 22 19:16 /tmp/blahblah.txt |
| 98 | + -rw-r--r-- 1 postgres postgres 47 janv. 22 19:24 /tmp/copy_blahblah.txt |
| 99 | + |
| 100 | + file=# SELECT id, readefile(the_file) FROM efile_test; |
| 101 | + id | readefile |
| 102 | + ----+-------------------------------------------------------------------------------------------------- |
| 103 | + 1 | \x48656c6c6f2c0a0a596f75206172652072656164696e67206120746578742066696c652e0a0a526567617264732c0a |
| 104 | + 2 | \x48656c6c6f2c0a0a596f75206172652072656164696e67206120746578742066696c652e0a0a526567617264732c0a |
| 105 | + (2 lines) |
| 106 | + |
| 107 | + |
| 108 | +4. Function reference |
| 109 | +===================== |
| 110 | + |
| 111 | +readEfile(e_file in efile) returns bytea |
| 112 | + copy the external file into a bytea. |
| 113 | + Error will be generated if something wrong. |
| 114 | + |
| 115 | +writeEfile(buffer in bytea, e_file in efile) returns void |
| 116 | + copy a bytea into a external file. |
| 117 | + Error will be generated if something wrong. |
| 118 | + |
| 119 | +copyEfile(src in efile, dest in efile) returns void |
| 120 | + duplicate file defined by src into file dest |
| 121 | + Error will be generated if something wrong. |
| 122 | + |
| 123 | +getEfilePath(e_file efile, need_read in boolean, need_write in boolean) returns text |
| 124 | + giving an efile and booleans, one for read and one for write need, return the |
| 125 | + full path for the file, otherwise an error is generated |
| 126 | + useful to check if session user has access to this external file |
| 127 | + |
| 128 | +5. License |
| 129 | +========== |
| 130 | + Author Dominique Legendre |
| 131 | + Copyright (c) 2012-2015 Brgm - All rights reserved. |
| 132 | + |
0 commit comments