diff --git a/README.md b/README.md index d8aa10d..d6a7ba0 100644 --- a/README.md +++ b/README.md @@ -130,6 +130,54 @@ lolor_db=# SELECT lo_unlink (1100449); (1 row) ``` +## Manage large objects + +`lolor` extension provide support for managing Large Objects similar to PostgreSQL native `lo` module. `spock.lo_manage` trigger function +can be used with trigger by attached tables that contain `LO` reference columns. + +### Example usage + +``` +CREATE EXTENSION lolor; + +-- example table and data +CREATE TABLE lotest(a INT PRIMARY KEY, + b OID +); + +INSERT INTO lotest + VALUES (1, lo_import('/etc/os-release')); + +-- check the large object oid +test_db=# SELECT * FROM lotest; + a | b +---+-------- + 1 | 412833 +(1 row) + +-- verify large object oid +test_db=# SELECT * FROM lolor.pg_largeobject_metadata WHERE oid = 412833; + oid | lomowner | lomacl +--------+----------+-------- + 412833 | 16384 | +(1 row) + +-- manage table and cleanup to avoid orphen large object +CREATE TRIGGER t_lotest BEFORE UPDATE OR DELETE ON lotest + FOR EACH ROW EXECUTE FUNCTION lolor.lo_manage(b); + +-- delete table record related to large object +test_db=# DELETE FROM lotest WHERE a = 1; +NOTICE: trigger t_lotest: (delete) removing large object oid 412833 +DELETE 1 + +-- related large object also deleted with the table record +test_db=# SELECT * FROM lolor.pg_largeobject_metadata where oid = 412833; + oid | lomowner | lomacl +-----+----------+-------- +(0 rows) +``` + ## Limitations - Native large object functionality cannot be used while you are using the lolor extension. diff --git a/lolor--1.0.sql b/lolor--1.0.sql index e21be36..a4fab83 100644 --- a/lolor--1.0.sql +++ b/lolor--1.0.sql @@ -188,4 +188,51 @@ CREATE FUNCTION pg_catalog.lo_on_drop_extension() CREATE EVENT TRIGGER lo_on_drop_extension ON ddl_command_start WHEN tag IN ('DROP EXTENSION') EXECUTE FUNCTION pg_catalog.lo_on_drop_extension(); -ALTER EVENT TRIGGER lo_on_drop_extension ENABLE ALWAYS; \ No newline at end of file +ALTER EVENT TRIGGER lo_on_drop_extension ENABLE ALWAYS; + +/* + clean up large object to avoid orphan large objects that are + no more associated with any table row in case of DELETE or UPDATE + operations +*/ +CREATE FUNCTION lolor.lo_manage() + RETURNS TRIGGER +AS $lo_manage$ +DECLARE + loid_old oid; + loid_new oid; +BEGIN + -- handle UPDATE or DELETE operation only + IF TG_OP != 'UPDATE' AND + TG_OP != 'DELETE' THEN + RAISE EXCEPTION 'Trigger function LO_MANAGE should be fired for UPDATE OR DELETE only'; + END IF; + + IF TG_NARGS < 1 THEN + RAISE EXCEPTION 'trigger %: no column name provided in the trigger definition', TG_NAME; + END IF; + IF TG_LEVEL != 'ROW' THEN + RAISE EXCEPTION 'trigger % should be fired for row', TG_NAME; + END IF; + IF NOT to_jsonb(OLD)?TG_ARGV[0] THEN + RAISE EXCEPTION 'trigger %: column "%" does not exist', TG_NAME, TG_ARGV[0]; + END IF; + + loid_old = (row_to_json(OLD)->>TG_ARGV[0])::oid; + loid_new = (row_to_json(NEW)->>TG_ARGV[0])::oid; + IF TG_OP = 'UPDATE' THEN + IF loid_old IS NOT NULL AND + (loid_old != loid_new OR loid_new IS NULL) THEN + -- take care of updated rows operation, in case large object id changes + RAISE NOTICE 'trigger %: (update) removing large object oid %', TG_NAME, loid_old; + PERFORM lo_unlink(loid_old); + END IF; + RETURN NEW; + ELSIF TG_OP = 'DELETE' THEN + -- take care of deleted row operation + RAISE NOTICE 'trigger %: (delete) removing large object oid %', TG_NAME, loid_old; + PERFORM lo_unlink(loid_old); + RETURN OLD; + END IF; +END; +$lo_manage$ LANGUAGE PLPGSQL;