diff --git a/.github/workflows/ci.yml b/.github/workflows/ci.yml new file mode 100644 index 0000000..9fb30d8 --- /dev/null +++ b/.github/workflows/ci.yml @@ -0,0 +1,26 @@ +name: CI +on: [push, pull_request] +jobs: + test: + strategy: + matrix: + pg: [17, 16, 15, 14, 13, 12, 11, 10] + name: 🐘 PostgreSQL ${{ matrix.pg }} + runs-on: ubuntu-latest + container: pgxn/pgxn-tools + steps: + - name: Start PostgreSQL ${{ matrix.pg }} + run: pg-start ${{ matrix.pg }} + - name: Check out the repo + uses: actions/checkout@v4 + - name: Test on PostgreSQL ${{ matrix.pg }} + run: make test PGUSER=postgres + continue-on-error: true + - name: Output failed results + run: | + if [ -e test/regression.out ]; then + ls -la /var/log + ls -la /var/log/postgresql/ + cat /var/log/postgresql/postgresql-${{ matrix.pg }}-test.log + exit 1 + fi diff --git a/.gitignore b/.gitignore index facf651..8e63124 100644 --- a/.gitignore +++ b/.gitignore @@ -28,3 +28,4 @@ regression.out # Misc tmp/ .DS_Store +.claude/settings.local.json diff --git a/.travis.yml b/.travis.yml deleted file mode 100644 index 0c4e016..0000000 --- a/.travis.yml +++ /dev/null @@ -1,13 +0,0 @@ -language: c -before_install: - - wget https://gist.github.com/petere/5893799/raw/apt.postgresql.org.sh - - sudo sh ./apt.postgresql.org.sh - - sudo sh -c "echo deb http://apt.postgresql.org/pub/repos/apt/ $(lsb_release -cs 2>/dev/null)-pgdg main $PGVERSION >> /etc/apt/sources.list.d/pgdg.list" -env: - - PGVERSION=9.6 - - PGVERSION=9.5 - - PGVERSION=9.4 - - PGVERSION=9.3 - - PGVERSION=9.2 - -script: bash ./pg-travis-test.sh diff --git a/META.in.json b/META.in.json index d01dc70..9a541be 100644 --- a/META.in.json +++ b/META.in.json @@ -81,6 +81,7 @@ }, "runtime": { "requires": { + "cat_tools": 0, "plpgsql": 0 } }, diff --git a/META.json b/META.json index 0512fbb..c56fae1 100644 --- a/META.json +++ b/META.json @@ -79,6 +79,7 @@ }, "runtime": { "requires": { + "cat_tools": 0, "plpgsql": 0 } }, diff --git a/Makefile b/Makefile index f5d2ff7..75543b6 100644 --- a/Makefile +++ b/Makefile @@ -3,7 +3,7 @@ include pgxntool/base.mk testdeps: $(wildcard test/*.sql test/helpers/*.sql) # Be careful not to include directories in this testdeps: test_factory -install: cat_tools count_nulls +install: cat_tools test: dump_test extra_clean += $(wildcard test/dump/*.log) @@ -15,10 +15,6 @@ cat_tools: $(DESTDIR)$(datadir)/extension/cat_tools.control $(DESTDIR)$(datadir)/extension/cat_tools.control: pgxn install --unstable cat_tools -.PHONY: count_nulls -count_nulls: $(DESTDIR)$(datadir)/extension/count_nulls.control -$(DESTDIR)$(datadir)/extension/count_nulls.control: - pgxn install --unstable count_nulls .PHONY: test_factory test_factory: $(DESTDIR)$(datadir)/extension/test_factory.control diff --git a/README.md b/README.md new file mode 100644 index 0000000..9bb1a6f --- /dev/null +++ b/README.md @@ -0,0 +1,333 @@ +# Object Reference Framework + +This framework provides tracking and management of references to database objects. It's designed to maintain referential integrity for objects that may be created, dropped, or renamed, and provides facilities for automatically capturing newly created objects into organized groups. + +Key capabilities: +- Track references to database objects that may be created, dropped, or renamed +- Group related objects for organization and DDL capture +- Automatically capture DDL operations to track new objects +- Manage dependencies between objects and external tables +- Support for object lifecycle management + +# A word on documentation... + +Good documentation should be like good code comments - explain things concisely without being overly verbose. Towards that end, this doc does *not* provide definition for things that should be inherently obvious, other than mentioning their existence. For example, we never define what is meant by `object_type`. The name itself should provide enough information. + +# Installation + +This extension depends on the `cat_tools` extension. + +```sql +CREATE EXTENSION object_reference CASCADE; +``` + +The extension creates two schemas: +- `object_reference` - Contains the public API functions +- `_object_reference` - Contains internal implementation details (do not use directly) + +To grant users access to the extension: +```sql +GRANT object_reference__usage TO role1, role2, role3; +``` + +# Security + +There are two roles associated with the extension: + +- `object_reference__usage` - Allows using the extension's public API functions. Grant this to users who need to track and manage object references. +- `object_reference__dependency` - Special role for creating foreign key dependencies to the internal object table. Only grant this to schemas/applications that need to create referential integrity constraints against the object tracking system. See [Referring to Objects](#referring-to-objects) below. + +Most users will only need `object_reference__usage`. The `object_reference__dependency` role is only needed when using `object__dependency__add()` or `object_group__dependency__add()` functions. + +# Key Concepts + +## Objects vs OIDs + +The framework separates object metadata (names, types, arguments) from their actual database OIDs. This allows tracking objects that don't exist yet, or that may be recreated. OID resolution is performed lazily - only when actually needed. + +## Object Groups + +Objects can be organized into named groups for logical organization. This is particularly useful for tracking all objects created during a specific operation or time period, especially when combined with DDL capture. + +## DDL Capture + +The framework can automatically capture newly created objects during DDL operations and add them to a specified object group. This is implemented using PostgreSQL event triggers. + +## Referring to Objects + +The framework supports removing objects that are no longer referenced. Because of this, *it is critical that any tables that store an `object_id` are registered with `object__dependency__add()`*. + +# API + +Note that all API routines live in the `object_reference` schema. Objects in the `_object_reference` schema are considered internal-only and should not be accessed directly. + +Most routines work with the `cat_tools.object_type` enum for specifying object types. You can also pass object types as text strings which will be converted automatically. + +## Core Object Functions + +### `object__getsert(...) RETURNS int` + +```sql +object__getsert( + object_type text | cat_tools.object_type + , object_name text + , secondary text DEFAULT NULL + , object_group_name text DEFAULT NULL + , loose boolean DEFAULT false +) RETURNS int +``` + +Get or insert an object reference, returning the `object_id`. This is the primary function for tracking objects. + +Arguments: +- `object_type` - Type of object (table, function, index, etc.) +- `object_name` - Fully qualified name of the object +- `secondary` - Additional identifier for objects that need it (e.g., function arguments) +- `object_group_name` - Optional object group to add this object to +- `loose` - If true, allows creating references to objects that don't exist + +### `object__getsert_w_group_id(...) RETURNS int` + +```sql +object__getsert_w_group_id( + object_type cat_tools.object_type + , object_name text + , secondary text DEFAULT NULL + , object_group_id int DEFAULT NULL + , loose boolean DEFAULT false +) RETURNS int +``` + +Same as `object__getsert()` but accepts a numeric `object_group_id` instead of group name. + +### `object__describe(object_id int) RETURNS text` + +Returns a human-readable description of the object, matching the format of PostgreSQL's `pg_describe_object()` function. + +### `object__identity(object_id int) RETURNS record` + +Returns object identification information matching the format of PostgreSQL's `pg_identify_object()` function. Returns a record with columns: `type`, `schema`, `name`, `identity`. + + +## Object Group Functions + +### `object_group__create(...) RETURNS int` + +```sql +object_group__create( + object_group_name text +) RETURNS int +``` + +Create a new object group and return its ID. + +### `object_group__get(...) RETURNS object_group` + +```sql +object_group__get( + object_group_name text | object_group_id int +) RETURNS _object_reference.object_group +``` + +Retrieve an object group by name or ID. Throws an error if the group doesn't exist. + +### `object_group__remove(...) RETURNS void` + +```sql +object_group__remove( + object_group_name text | object_group_id int + , force boolean DEFAULT false +) RETURNS void +``` + +Remove an object group. This does not delete the objects themselves, only the grouping. + +### `object_group__object__add(...) RETURNS void` + +```sql +object_group__object__add( + object_group_id int + , object_id int +) RETURNS void +``` + +Add an existing object to an object group. + +### `object_group__object__remove(...) RETURNS void` + +```sql +object_group__object__remove( + object_group_id int + , object_id int +) RETURNS void +``` + +Remove an object from an object group. + +## Dependency Functions + +These functions create foreign key dependencies to the object tracking system. They require the `object_reference__dependency` role. + +### `object__dependency__add(...) RETURNS void` + +```sql +object__dependency__add( + table_name text + , field_name name +) RETURNS void +``` + +Create a foreign key dependency from the specified table to the object tracking system. + +Arguments: +- `table_name` - Name of table to add dependency to +- `field_name` - Name of the field to create the foreign key on + +### `object_group__dependency__add(...) RETURNS void` + +```sql +object_group__dependency__add( + table_name text + , field_name name +) RETURNS void +``` + +Create a foreign key dependency from the specified table to the object group system. + +## DDL Capture Functions + +DDL capture allows you to automatically track objects created during DDL operations. + +### `capture__start(...) RETURNS int` + +```sql +capture__start( + object_group_name text | object_group_id int +) RETURNS int +``` + +Begin capturing newly created objects to the specified group. The group must +already exist. Returns the capture level (for nested captures). + +### `capture__stop(...) RETURNS void` + +```sql +capture__stop( + object_group_name text | object_group_id int +) RETURNS void +``` + +Stop capturing objects to the specified group. + +### `capture__get_current(...) RETURNS record` + +```sql +capture__get_current( + OUT capture_level int + , OUT object_group_id int +) RETURNS record +``` + +Get information about the current capture state. + +### `capture__get_all(...) RETURNS SETOF record` + +```sql +capture__get_all( + OUT capture_level int + , OUT object_group_id int +) RETURNS SETOF record +``` + +Get information about all active capture levels. + +## Utility Functions + +### `post_restore() RETURNS void` + +```sql +post_restore() RETURNS void +``` + +Ensures all object references are correct after a database restore. Run this after restoring from backup to fix any OID mismatches. + +### `object__cleanup(object_id int) RETURNS void` + +```sql +object__cleanup(object_id int) RETURNS void +``` + +Attempts to delete an object from the tracking system. Silently returns if the object is still referenced by other tables (via foreign keys). This function is automatically called when objects are removed from object groups. + +### Object Type Information Functions + +**Get lists of unsupported/untested object types:** + +```sql +unsupported() RETURNS cat_tools.object_type[] +unsupported_srf() RETURNS SETOF cat_tools.object_type + +untested() RETURNS cat_tools.object_type[] +untested_srf() RETURNS SETOF cat_tools.object_type +``` + +**Check if specific object types are supported/tested:** + +```sql +unsupported(object_type text | cat_tools.object_type) RETURNS boolean +untested(object_type text | cat_tools.object_type) RETURNS boolean +``` + +These functions help determine which object types are supported by the framework. Unsupported types cannot be tracked, while untested types may work but haven't been fully validated. + +# Event Triggers + +The extension automatically installs several event triggers that: + +- Capture object creation when DDL capture is active +- Update object identity information when objects are renamed +- Clean up object references when objects are dropped + +These event triggers operate transparently and require no user intervention. However, be aware that they may add slight overhead to DDL operations. + +# Examples + +## Basic Object Tracking + +```sql +-- Track a table +SELECT object_reference.object__getsert('table', 'public.my_table'); + +-- Track a function with its signature +SELECT object_reference.object__getsert('function', 'public.my_func', 'integer, text'); +``` + +## Using Object Groups + +```sql +-- Create a group for related objects +SELECT object_reference.object_group__create('my_feature_objects'); + +-- Add objects to the group +SELECT object_reference.object__getsert('table', 'public.feature_table', NULL, 'my_feature_objects'); +SELECT object_reference.object__getsert('view', 'public.feature_view', NULL, 'my_feature_objects'); +``` + +## DDL Capture + +```sql +-- Create a group first +SELECT object_reference.object_group__create('migration_v2_objects'); + +-- Start capturing new objects to that group +SELECT object_reference.capture__start('migration_v2_objects'); + +-- Run your DDL commands +CREATE TABLE public.new_table (id int, name text); +CREATE INDEX idx_new_table_name ON public.new_table (name); + +-- Stop capturing +SELECT object_reference.capture__stop('migration_v2_objects'); + +-- All objects created between start/stop are now tracked in the 'migration_v2_objects' group +``` \ No newline at end of file diff --git a/object_reference.control b/object_reference.control index 8200390..c03010e 100644 --- a/object_reference.control +++ b/object_reference.control @@ -2,4 +2,4 @@ comment = 'Provides reference IDs for database objects' default_version = '0.1.0' relocatable = false schema = 'object_reference' -requires = 'cat_tools, count_nulls' +requires = 'cat_tools' diff --git a/pg-travis-test.sh b/pg-travis-test.sh deleted file mode 100644 index f63ae43..0000000 --- a/pg-travis-test.sh +++ /dev/null @@ -1,36 +0,0 @@ -#!/bin/bash - -# Based on https://gist.github.com/petere/6023944 - -set -eux - -sudo apt-get update - -packages="python-setuptools postgresql-$PGVERSION postgresql-server-dev-$PGVERSION postgresql-common" - -# bug: http://www.postgresql.org/message-id/20130508192711.GA9243@msgid.df7cb.de -sudo update-alternatives --remove-all postmaster.1.gz - -# stop all existing instances (because of https://github.com/travis-ci/travis-cookbooks/pull/221) -sudo service postgresql stop -# and make sure they don't come back -echo 'exit 0' | sudo tee /etc/init.d/postgresql -sudo chmod a+x /etc/init.d/postgresql - -sudo apt-get -o Dpkg::Options::="--force-confdef" -o Dpkg::Options::="--force-confold" install $packages - -sudo easy_install pgxnclient - -PGPORT=55435 -PGCLUSTER_NAME=test - -export PGCLUSTER=9.6/$PGCLUSTER_NAME -env | grep PG -which pg_dump - -sudo pg_createcluster --start $PGVERSION $PGCLUSTER_NAME -p $PGPORT -- -A trust - -# TODO: have base.mk support dynamic sudo -sudo PGPORT=$PGPORT PGUSER=postgres PG_CONFIG=/usr/lib/postgresql/$PGVERSION/bin/pg_config make test - -[ ! -e test/regression.diffs ] diff --git a/pgxntool/HISTORY.asc b/pgxntool/HISTORY.asc index b69c9d1..9cb793b 100644 --- a/pgxntool/HISTORY.asc +++ b/pgxntool/HISTORY.asc @@ -1,5 +1,11 @@ STABLE ------ +== Support 13+ +The `--load-language` option was removed from `pg_regress` in 13. + +== Reduce verbosity from test setup +As part of this change, you will want to review the changes to test/deps.sql. + === Support asciidoc documentation targets By default, if asciidoctor or asciidoc exists on the system, any files in doc/ that end in .adoc or .asciidoc will be processed to html. See the README for full details. @@ -12,11 +18,12 @@ If a test input file changes we certainly need to re-run tests. === Have test/pgxntool/setup.sql install tap before running deps.sql -=== Reduce verbosity from test setup -As part of this change, you will want to review the changes to test/deps.sql. - === Support other asciidoc extensions +=== Create the test/sql/ directory during setup + +=== Use `--sudo` option when installing pgtap + 0.2.0 ----- ### Stop using $(VERSION) diff --git a/pgxntool/base.mk b/pgxntool/base.mk index ce918db..a976ebb 100644 --- a/pgxntool/base.mk +++ b/pgxntool/base.mk @@ -36,7 +36,7 @@ TEST_SQL_FILES += $(wildcard $(TESTDIR)/sql/*.sql) TEST_RESULT_FILES = $(patsubst $(TESTDIR)/sql/%.sql,$(TESTDIR)/expected/%.out,$(TEST_SQL_FILES)) TEST_FILES = $(TEST_SOURCE_FILES) $(TEST_SQL_FILES) REGRESS = $(sort $(notdir $(subst .source,,$(TEST_FILES:.sql=)))) # Sort is to get unique list -REGRESS_OPTS = --inputdir=$(TESTDIR) --outputdir=$(TESTOUT) --load-language=plpgsql +REGRESS_OPTS = --inputdir=$(TESTDIR) --outputdir=$(TESTOUT) # See additional setup below MODULES = $(patsubst %.c,%,$(wildcard src/*.c)) ifeq ($(strip $(MODULES)),) MODULES =# Set to NUL so PGXS doesn't puke @@ -57,8 +57,10 @@ GE91 = $(call test, $(MAJORVER), -ge, 91) ifeq ($(GE91),yes) all: $(EXTENSION_VERSION_FILES) +endif -#DATA = $(wildcard sql/*--*.sql) +ifeq ($($call test, $(MAJORVER), -lt 13), yes) + REGRESS_OPTS += --load-language=plpgsql endif PGXS := $(shell $(PG_CONFIG) --pgxs) @@ -77,8 +79,12 @@ installcheck: $(TEST_RESULT_FILES) $(TEST_OUT_FILES) $(TEST_SQL_FILES) $(TEST_SO # make test: run any test dependencies, then do a `make install installcheck`. # If regressions are found, it will output them. +# +# This used to depend on clean as well, but that causes problems with +# watch-make if you're generating intermediate files. If tests end up needing +# clean it's an indication of a missing dependency anyway. .PHONY: test -test: clean testdeps install installcheck +test: testdeps install installcheck @if [ -r $(TESTOUT)/regression.diffs ]; then cat $(TESTOUT)/regression.diffs; fi # make results: runs `make test` and copy all result files to expected @@ -220,6 +226,6 @@ installcheck: pgtap pgtap: $(DESTDIR)$(datadir)/extension/pgtap.control $(DESTDIR)$(datadir)/extension/pgtap.control: - pgxn install pgtap + pgxn install pgtap --sudo endif # fndef PGXNTOOL_NO_PGXS_INCLUDE diff --git a/pgxntool/setup.sh b/pgxntool/setup.sh index 3730a2b..881ccaa 100755 --- a/pgxntool/setup.sh +++ b/pgxntool/setup.sh @@ -46,6 +46,7 @@ git add META.json mkdir -p sql test src cd test +mkdir -p sql safecp ../pgxntool/test/deps.sql deps.sql [ -d pgxntool ] || ln -s ../pgxntool/test/pgxntool . git add pgxntool diff --git a/sql/.object_reference.sql.swo b/sql/.object_reference.sql.swo deleted file mode 100644 index b3912fe..0000000 Binary files a/sql/.object_reference.sql.swo and /dev/null differ diff --git a/sql/object_reference.sql b/sql/object_reference.sql index 44dc1c6..e381023 100644 --- a/sql/object_reference.sql +++ b/sql/object_reference.sql @@ -3,35 +3,6 @@ SET LOCAL client_min_messages = WARNING; \echo You really, REALLY do NOT want to try and load this via psql!!! \echo It will FAIL during pg_dump! \quit --- This BS is because count_nulls is relocatable, so could be in any schema -DO $$ -BEGIN - RAISE DEBUG 'initial search_path = %', current_setting('search_path'); - PERFORM set_config('search_path', current_setting('search_path') || ', ' || extnamespace::regnamespace::text, true) -- true = local only - FROM pg_extension - WHERE extname = 'count_nulls' - ; - RAISE DEBUG 'search_path changed to %', current_setting('search_path'); -END -$$; -/* -DO $$ -DECLARE - c_schema CONSTANT name := (SELECT extnamespace::regnamespace::text FROM pg_extension WHERE extname = 'cat_tools'); -BEGIN - IF c_schema IS NULL THEN - RAISE 'extension cat_tools is not installed'; - END IF; - - IF c_schema <> 'cat_tools' THEN - RAISE 'having the cat_tools extension installed anywhere but the "cat_tools" schema is not currently supported' - USING DETAIL = format('current schema for cat_tools is %s', c_schema) - ; - END IF; -END -$$; -*/ - DO $$ BEGIN CREATE ROLE object_reference__usage NOLOGIN; @@ -85,7 +56,7 @@ CREATE FUNCTION __object_reference.create_function( , grants text DEFAULT NULL ) RETURNS void LANGUAGE plpgsql AS $body$ DECLARE - c_clean_args text := cat_tools.function__arg_types_text(args); + c_clean_args text := cat_tools.routine__parse_arg_types_text(args); create_template CONSTANT text := $template$ CREATE OR REPLACE FUNCTION %s( @@ -192,7 +163,7 @@ GRANT REFERENCES ON _object_reference.object TO object_reference__dependency; CREATE TABLE _object_reference._object_oid( object_id int PRIMARY KEY REFERENCES _object_reference.object ON DELETE CASCADE ON UPDATE CASCADE - , classid regclass NOT NULL + , classid oid NOT NULL /* TODO: needs to be a trigger CONSTRAINT classid_must_match__object__address_classid CHECK( classid IS NOT DISTINCT FROM cat_tools.object__address_classid(object_type) ) @@ -200,50 +171,11 @@ CREATE TABLE _object_reference._object_oid( , objid oid NOT NULL , objsubid int NOT NULL CONSTRAINT objid_must_match CHECK( -- _object_reference._sanity() depends on this! - objid IS NOT DISTINCT FROM coalesce( - regclass::oid -- Need to cast first item to generic OID - , regconfig - , regdictionary - , regnamespace -- SED: REQUIRES 9.5! - , regoperator - , regprocedure - , regtype - , object_oid - ) + objid IS NOT DISTINCT FROM object_oid ) , CONSTRAINT object__u_classid__objid__objsubid UNIQUE( classid, objid, objsubid ) - , regclass regclass - CONSTRAINT regclass_classid CHECK( regclass IS NULL OR classid = cat_tools.object__reg_type_catalog('regclass') ) - , regconfig regconfig - CONSTRAINT regconfig_classid CHECK( regconfig IS NULL OR classid = cat_tools.object__reg_type_catalog('regconfig') ) - , regdictionary regdictionary - CONSTRAINT regdictionary_classid CHECK( regdictionary IS NULL OR classid = cat_tools.object__reg_type_catalog('regdictionary') ) - , regnamespace regnamespace -- SED: REQUIRES 9.5! - CONSTRAINT regnamespace_classid CHECK( regnamespace IS NULL OR classid = cat_tools.object__reg_type_catalog('regnamespace') ) -- SED: REQUIRES 9.5! - , regoperator regoperator - CONSTRAINT regoperator_classid CHECK( regoperator IS NULL OR classid = cat_tools.object__reg_type_catalog('regoperator') ) - , regprocedure regprocedure - CONSTRAINT regprocedure_classid CHECK( regprocedure IS NULL OR classid = cat_tools.object__reg_type_catalog('regprocedure') ) - -- I don't think we should ever have regrole since we can't create event triggers on it --- , regrole regrole - , regtype regtype - CONSTRAINT regtype_classid CHECK( regtype IS NULL OR classid = cat_tools.object__reg_type_catalog('regtype') ) - , object_oid oid + , object_oid oid NOT NULL ); -CREATE TRIGGER null_count - AFTER INSERT OR UPDATE - ON _object_reference._object_oid - FOR EACH ROW EXECUTE PROCEDURE not_null_count_trigger( - 5 -- First 4 fields, + 1 - , 'only one object reference field may be set' - ) -; -CREATE UNIQUE INDEX _object_oid__u_regclass ON _object_reference._object_oid(regclass) WHERE regclass IS NOT NULL; -CREATE UNIQUE INDEX _object_oid__u_regconfig ON _object_reference._object_oid(regconfig) WHERE regconfig IS NOT NULL; -CREATE UNIQUE INDEX _object_oid__u_regdictionary ON _object_reference._object_oid(regdictionary) WHERE regdictionary IS NOT NULL; -CREATE UNIQUE INDEX _object_oid__u_regoperator ON _object_reference._object_oid(regoperator) WHERE regoperator IS NOT NULL; -CREATE UNIQUE INDEX _object_oid__u_regprocedure ON _object_reference._object_oid(regprocedure) WHERE regprocedure IS NOT NULL; -CREATE UNIQUE INDEX _object_oid__u_regtype ON _object_reference._object_oid(regtype) WHERE regtype IS NOT NULL; SELECT __object_reference.create_function( '_object_reference._sanity' @@ -303,13 +235,6 @@ CREATE VIEW _object_reference._object_v AS , i.classid , i.objid , i.objsubid - , i.regclass - , i.regconfig - , i.regdictionary - , i.regnamespace - , i.regoperator - , i.regprocedure - , i.regtype , i.object_oid , s.* FROM _object_reference.object o @@ -325,13 +250,6 @@ CREATE VIEW _object_reference._object_v__for_update AS , i.classid , i.objid , i.objsubid - , i.regclass - , i.regconfig - , i.regdictionary - , i.regnamespace - , i.regoperator - , i.regprocedure - , i.regtype , i.object_oid , s.* FROM _object_reference.object o @@ -363,26 +281,9 @@ BEGIN WHERE o.object_id = _object_oid__add.object_id ; END IF; - DECLARE - c_reg_type name := cat_tools.object__reg_type(object_type); -- Verifies regtype is supported, if there is one - c_oid_field CONSTANT name := coalesce(c_reg_type, 'object_oid'); - - c_oid_insert CONSTANT text := format( - --USING object_id, classid, objid, objsubid - $$INSERT INTO _object_reference._object_oid(object_id, classid, objid, objsubid, %I) - SELECT $1, $2, $3, $4, $3::%I$$ - , c_oid_field - , coalesce(c_reg_type, 'oid') - ) - ; BEGIN - RAISE DEBUG E'%\n USING %, %, %, %' - , c_oid_insert - , object_id, classid, objid, objsubid - ; - EXECUTE c_oid_insert - USING object_id, classid, objid, objsubid - ; + INSERT INTO _object_reference._object_oid(object_id, classid, objid, objsubid, object_oid) + VALUES (object_id, classid, objid, objsubid, objid); SELECT INTO STRICT r_object_v -- Record better exist! * @@ -627,6 +528,23 @@ CREATE TABLE _object_reference.object_group__object( ); SELECT __object_reference.safe_dump('_object_reference.object_group__object'); +-- Trigger function for automatic object cleanup +SELECT __object_reference.create_function( + '_object_reference._object_group__object__cleanup_trigger' + , '' + , 'trigger LANGUAGE plpgsql' + , $body$ +BEGIN + PERFORM object_reference.object__cleanup(OLD.object_id); + RETURN OLD; +END +$body$ + , 'Trigger function to automatically attempt cleanup of objects when removed from groups.' +); +CREATE TRIGGER object_group__object__cleanup + AFTER DELETE ON _object_reference.object_group__object + FOR EACH ROW + EXECUTE FUNCTION _object_reference._object_group__object__cleanup_trigger(); -- __get SELECT __object_reference.create_function( 'object_reference.object_group__get' @@ -830,7 +748,68 @@ $body$ , 'Add a foreign key from . to the object table.' , 'object_reference__dependency' ); +/* + * OBJECT INFO FUNCTIONS + */ +SELECT __object_reference.create_function( + 'object_reference.object__describe' + , $args$ + object_id int +$args$ + , 'text LANGUAGE sql' + , $body$ +SELECT pg_catalog.pg_describe_object( + o.classid, + o.objid, + o.objsubid +) +FROM _object_reference._object_oid o +WHERE o.object_id = $1 +$body$ + , 'Return a human-readable description of the object, matching pg_describe_object() format.' + , 'object_reference__usage' +); +SELECT __object_reference.create_function( + 'object_reference.object__identity' + , $args$ + object_id int + , OUT type text + , OUT schema text + , OUT name text + , OUT identity text +$args$ + , 'record LANGUAGE sql' + , $body$ +SELECT + i.type::text, + i.schema::text, + i.name::text, + i.identity::text +FROM _object_reference._object_oid o, + LATERAL pg_catalog.pg_identify_object(o.classid, o.objid, o.objsubid) i +WHERE o.object_id = $1 +$body$ + , 'Return object identification information matching pg_identify_object() format.' + , 'object_reference__usage' +); +SELECT __object_reference.create_function( + 'object_reference.object__cleanup' + , $args$ + object_id int +$args$ + , 'void LANGUAGE plpgsql' + , $body$ +BEGIN + DELETE FROM _object_reference.object WHERE object.object_id = object__cleanup.object_id; +EXCEPTION WHEN foreign_key_violation THEN + -- Object is still referenced elsewhere, ignore the error + NULL; +END +$body$ + , 'Attempts to delete an object from the tracking system. Silently returns if the object is still referenced by other tables.' + , 'object_reference__usage' +); /* * OBJECT GETSERT */ @@ -850,6 +829,7 @@ DECLARE r_object_v _object_reference._object_v; r_address record; + r_identity record; did_insert boolean := false; @@ -878,6 +858,15 @@ BEGIN ; END IF; + -- Refuse to track objects in temporary schemas + SELECT INTO r_identity * FROM pg_catalog.pg_identify_object(c_classid, objid, objsubid); + IF r_identity.schema IS NOT NULL AND (r_identity.schema LIKE 'pg_temp%' OR r_identity.schema LIKE 'pg_toast_temp%') THEN + RAISE 'cannot track temporary object' + USING DETAIL = format('object %s is in temporary schema %s', r_identity.identity, r_identity.schema) + , ERRCODE = 'feature_not_supported' + ; + END IF; + -- Ensure the object record exists SELECT INTO r_object_v * diff --git a/test/deps.sql b/test/deps.sql index e1a53c8..d13a016 100644 --- a/test/deps.sql +++ b/test/deps.sql @@ -4,6 +4,5 @@ /* * Normally these should be loaded by the cascade! -CREATE EXTENSION IF NOT EXISTS count_nulls; CREATE EXTENSION IF NOT EXISTS cat_tools; */ diff --git a/test/dump/run.sh b/test/dump/run.sh index 4d0c7a3..6896f68 100755 --- a/test/dump/run.sh +++ b/test/dump/run.sh @@ -26,7 +26,7 @@ if [ "$1" == "-f" ]; then fi echo Creating dump database -createdb test_dump && psql -f test/dump/load_all.sql test_dump > $create_log || die 3 "Unable to create dump database" +createdb test_dump && psql -Xf test/dump/load_all.sql test_dump > $create_log || die 3 "Unable to create dump database" # Ensure no errors in log check_log() { @@ -45,8 +45,8 @@ check_log $create_log creation echo Running dump and restore # No real need to cat the log on failure here; psql will generate an error and even if not verify will almost certainly catch it -createdb test_load && PAGER='' psql -c '\df pg_get_object_address' test_load || die 5 'crap' -(echo 'BEGIN;' && pg_dump test_dump && echo 'COMMIT;') | psql -q -v VERBOSITY=verbose -v ON_ERROR_STOP=true test_load > $restore_log +createdb test_load && PAGER='' psql -Xc '\df pg_get_object_address' test_load || die 5 'crap' +(echo 'BEGIN;' && pg_dump test_dump && echo 'COMMIT;') | psql -q -X -v VERBOSITY=verbose -v ON_ERROR_STOP=true test_load > $restore_log rc=$? if [ $rc -ne 0 ]; then cat $restore_log @@ -54,7 +54,7 @@ if [ $rc -ne 0 ]; then fi echo Verifying restore -psql -f test/dump/verify.sql test_load > $verify_log || die 5 "Test failed" +psql -Xf test/dump/verify.sql test_load > $verify_log || die 5 "Test failed" check_log $create_log verify diff --git a/test/expected/base.out b/test/expected/base.out index 5e39f56..5357054 100644 --- a/test/expected/base.out +++ b/test/expected/base.out @@ -1,12 +1,13 @@ \set ECHO none -1..9 +1..10 ok 1 - Role object_reference__dependency should be granted USAGE on schema _object_reference ok 2 - Role object_reference__dependency should be granted REFERENCES on table _object_reference.object ok 3 - CREATE TEMP TABLE test_object AS SELECT object_reference.object__getsert('table', 'test_table') AS object_id; -ok 4 - Verify regclass field is correct -ok 5 - Existing object works, provides correct ID -ok 6 - secondary may not be specified for table objects -ok 7 - Verify count_nulls extension can not be relocated -ok 8 - Still works after moving the count_nulls extension -ok 9 - CREATE EXTENSION test_factory +ok 4 - Verify object_oid field is correct +ok 5 - object__describe returns same result as pg_describe_object +ok 6 - object__identity returns same result as pg_identify_object +ok 7 - Existing object works, provides correct ID +ok 8 - secondary may not be specified for table objects +ok 9 - temp objects are rejected +ok 10 - CREATE EXTENSION test_factory # TRANSACTION INTENTIONALLY LEFT OPEN! diff --git a/test/expected/object_group.out b/test/expected/object_group.out index d286833..e670106 100644 --- a/test/expected/object_group.out +++ b/test/expected/object_group.out @@ -1,5 +1,5 @@ \set ECHO none -1..24 +1..29 ok 1 - Register test table 1 ok 2 - object_group__create(...) for group name that is too long throws error ok 3 - object_group__create('object reference test group') @@ -24,6 +24,9 @@ ok 21 - object_group__object__add(...)for missing group throws error ok 22 - Removing group with items in it fails ok 23 - __object__remove() for col1 works ok 24 - __object__remove() for test_table_2 works -ok 25 - Removing empty group works -# Looks like you planned 24 tests but ran 25 +ok 25 - Add test table back to group for cleanup test +ok 26 - Object exists before cleanup test +ok 27 - Remove from group triggers automatic cleanup attempt +ok 28 - Object was automatically cleaned up after group removal +ok 29 - Removing empty group works # TRANSACTION INTENTIONALLY LEFT OPEN! diff --git a/test/expected/zzz_build.out b/test/expected/zzz_build.out index fe92660..ff07ade 100644 --- a/test/expected/zzz_build.out +++ b/test/expected/zzz_build.out @@ -2,16 +2,16 @@ This extension must be loaded via CREATE EXTENSION object_reference; You really, REALLY do NOT want to try and load this via psql!!! -psql:test/temp_load.not_sql:188: WARNING: I promise you will be sorry if you try to use this as anything other than an extension! +psql:test/temp_load.not_sql:159: WARNING: I promise you will be sorry if you try to use this as anything other than an extension! -psql:test/temp_load.not_sql:189: WARNING: I promise you will be sorry if you try to use this as anything other than an extension! +psql:test/temp_load.not_sql:160: WARNING: I promise you will be sorry if you try to use this as anything other than an extension! -psql:test/temp_load.not_sql:513: WARNING: I promise you will be sorry if you try to use this as anything other than an extension! +psql:test/temp_load.not_sql:414: WARNING: I promise you will be sorry if you try to use this as anything other than an extension! @@ -21,9 +21,13 @@ psql:test/temp_load.not_sql:513: WARNING: I promise you will be sorry if you tr -psql:test/temp_load.not_sql:620: WARNING: I promise you will be sorry if you try to use this as anything other than an extension! +psql:test/temp_load.not_sql:521: WARNING: I promise you will be sorry if you try to use this as anything other than an extension! + +psql:test/temp_load.not_sql:528: WARNING: I promise you will be sorry if you try to use this as anything other than an extension! + + + -psql:test/temp_load.not_sql:627: WARNING: I promise you will be sorry if you try to use this as anything other than an extension! diff --git a/test/load.sql b/test/load.sql index 0f1c6be..f1b267f 100644 --- a/test/load.sql +++ b/test/load.sql @@ -1,6 +1,5 @@ \i test/pgxntool/setup.sql --- Need to add count_nulls back into the path SET search_path = tap, public; -- Don't use IF NOT EXISTS here; we want to ensure we always have the latest code diff --git a/test/sql/base.sql b/test/sql/base.sql index 202ae5f..5fa9918 100644 --- a/test/sql/base.sql +++ b/test/sql/base.sql @@ -8,8 +8,8 @@ SELECT plan( 0 +1 -- schema +3 -- initial - +2 -- errors - +2 -- move + +2 -- new functions + +3 -- errors (includes temp object test) +1 -- create extensions ); @@ -32,9 +32,23 @@ SELECT lives_ok( , $$CREATE TEMP TABLE test_object AS SELECT object_reference.object__getsert('table', 'test_table') AS object_id;$$ ); SELECT is( - (SELECT regclass FROM _object_reference._object_v WHERE object_id = (SELECT object_id FROM test_object)) - , 'test_table'::regclass - , 'Verify regclass field is correct' + (SELECT object_oid FROM _object_reference._object_v WHERE object_id = (SELECT object_id FROM test_object)) + , 'test_table'::regclass::oid + , 'Verify object_oid field is correct' +); + +-- Test object__describe function +SELECT is( + object_reference.object__describe((SELECT object_id FROM test_object)) + , pg_catalog.pg_describe_object('pg_class'::regclass, 'test_table'::regclass, 0) + , 'object__describe returns same result as pg_describe_object' +); + +-- Test object__identity function +SELECT results_eq( + $$SELECT * FROM object_reference.object__identity((SELECT object_id FROM test_object))$$ + , $$SELECT type, schema, name, identity FROM pg_catalog.pg_identify_object('pg_class'::regclass, 'test_table'::regclass, 0)$$ + , 'object__identity returns same result as pg_identify_object' ); SELECT is( object_reference.object__getsert('table', 'test_table') @@ -50,24 +64,13 @@ SELECT throws_ok( , 'secondary may not be specified for table objects' ); -/* - * I'm not sure if our extension would continue working if count_nulls was - * relocated. Currently a moot point since relocation isn't supported, but I'd - * already coded the second test so might as well leave it here in case it - * changes in the future. - */ -\set null_schema test_relocate_count_nulls -CREATE SCHEMA :null_schema; +-- Test temp object rejection +CREATE TEMP TABLE temp_test_table(); SELECT throws_ok( - $$ALTER EXTENSION count_nulls SET SCHEMA $$ || :'null_schema' - , '0A000' - , NULL - , 'Verify count_nulls extension can not be relocated' -); -SELECT is( - object_reference.object__getsert('table', 'test_table') - , (SELECT object_id FROM test_object) - , 'Still works after moving the count_nulls extension' + $$SELECT object_reference.object__getsert('table', 'temp_test_table')$$ + , '0A000' -- feature_not_supported + , 'cannot track temporary object' + , 'temp objects are rejected' ); -- Create extensions diff --git a/test/sql/object_group.sql b/test/sql/object_group.sql index 6304892..bef342a 100644 --- a/test/sql/object_group.sql +++ b/test/sql/object_group.sql @@ -2,8 +2,8 @@ \i test/load.sql -CREATE TEMP TABLE test_table_1(col1 int, col2 int); -CREATE TEMP TABLE test_table_2(col1 int, col2 int); +CREATE TABLE object_group_test_table_1(col1 int, col2 int); +CREATE TABLE object_group_test_table_2(col1 int, col2 int); CREATE FUNCTION pg_temp.bogus_group( command_template text @@ -40,10 +40,12 @@ SELECT plan( +4 -- __object__remove +4 + 2 -- __remove + +4 -- cleanup tests + +1 -- final group removal (there was always an extra test) ); SELECT lives_ok( - $$CREATE TEMP TABLE test_table_1_id AS SELECT * FROM object_reference.object__getsert('table', 'test_table_1')$$ + $$CREATE TEMP TABLE test_table_1_id AS SELECT * FROM object_reference.object__getsert('table', 'object_group_test_table_1')$$ , 'Register test table 1' ); @@ -102,37 +104,37 @@ SELECT lives_ok( -- object__getsert SELECT throws_ok( -- Can't use helper here - $$CREATE TEMP TABLE col1_id AS SELECT * FROM object_reference.object__getsert('table column', 'test_table_1', 'col1', 'absurd group name used only for testing purposes ktxbye')$$ + $$CREATE TEMP TABLE col1_id AS SELECT * FROM object_reference.object__getsert('table column', 'object_group_test_table_1', 'col1', 'absurd group name used only for testing purposes ktxbye')$$ , 'P0002' , 'object group "absurd group name used only for testing purposes ktxbye" does not exist' , 'object__getsert with bogus group name' ); /* TODO SELECT throws_ok( -- Can't use helper here - $$CREATE TEMP TABLE col1_id AS SELECT * FROM object_reference.object__getsert_w_group_id('table column', 'test_table_1', 'col1', -1)$$ + $$CREATE TEMP TABLE col1_id AS SELECT * FROM object_reference.object__getsert_w_group_id('table column', 'object_group_test_table_1', 'col1', -1)$$ , '' , '' , 'object__getsert with bogus group id' ); */ SELECT lives_ok( - $$CREATE TEMP TABLE col1_id AS SELECT * FROM object_reference.object__getsert('table column', 'test_table_1', 'col1', 'object reference test group')$$ + $$CREATE TEMP TABLE col1_id AS SELECT * FROM object_reference.object__getsert('table column', 'object_group_test_table_1', 'col1', 'object reference test group')$$ , 'Register test column' ); SELECT lives_ok( - $$CREATE TEMP TABLE test_table_2_id AS SELECT * FROM object_reference.object__getsert('table', 'test_table_2', object_group_name := 'object reference test group')$$ + $$CREATE TEMP TABLE test_table_2_id AS SELECT * FROM object_reference.object__getsert('table', 'object_group_test_table_2', object_group_name := 'object reference test group')$$ , 'Register test table 2' ); -- Drop tests SELECT throws_ok( - $$ALTER TABLE test_table_1 DROP COLUMN col1$$ + $$ALTER TABLE object_group_test_table_1 DROP COLUMN col1$$ , '23503' , NULL -- current error is crap anyway , 'Dropping col1 fails' ); SELECT throws_ok( - $$DROP TABLE test_table_2$$ + $$DROP TABLE object_group_test_table_2$$ , '23503' , NULL -- current error is crap anyway , 'Dropping test_table_2 fails' @@ -144,7 +146,7 @@ SELECT throws_ok( , 'Removing test group fails' ); SELECT lives_ok( - $$ALTER TABLE test_table_1 DROP COLUMN col2$$ + $$ALTER TABLE object_group_test_table_1 DROP COLUMN col2$$ , 'Dropping col2 works' ); @@ -178,7 +180,7 @@ SELECT lives_ok( , '__object__remove() for test_table_1 works' ); SELECT throws_ok( - $$DROP TABLE test_table_1$$ -- Should not work because column is still registered + $$DROP TABLE object_group_test_table_1$$ -- Should not work because column is still registered , '23503' , NULL -- current error is crap anyway , 'Dropping test_table_1 fails' @@ -211,6 +213,26 @@ SELECT lives_ok( ) , '__object__remove() for test_table_2 works' ); + +-- Test automatic cleanup via trigger +SELECT lives_ok( + $$CREATE TEMP TABLE cleanup_test_id AS SELECT * FROM object_reference.object__getsert('table', 'object_group_test_table_1', object_group_name := 'object reference test group')$$ + , 'Add test table back to group for cleanup test' +); +SELECT ok( + EXISTS(SELECT 1 FROM _object_reference.object WHERE object_id = (SELECT object__getsert FROM cleanup_test_id)) + , 'Object exists before cleanup test' +); +SELECT lives_ok( + $$DELETE FROM _object_reference.object_group__object WHERE object_id = (SELECT object__getsert FROM cleanup_test_id)$$ + , 'Remove from group triggers automatic cleanup attempt' +); +-- Object should be deleted because it's no longer in any group and trigger calls cleanup +SELECT ok( + NOT EXISTS(SELECT 1 FROM _object_reference.object WHERE object_id = (SELECT object__getsert FROM cleanup_test_id)) + , 'Object was automatically cleaned up after group removal' +); + SELECT lives_ok( $$SELECT object_reference.object_group__remove('object reference test group')$$ , 'Removing empty group works' diff --git a/test/sql/zzz_build.sql b/test/sql/zzz_build.sql index 4da65b4..4fc0628 100644 --- a/test/sql/zzz_build.sql +++ b/test/sql/zzz_build.sql @@ -6,7 +6,6 @@ -- Loads deps, but not extension itself \i test/pgxntool/setup.sql -CREATE EXTENSION IF NOT EXISTS count_nulls; CREATE EXTENSION IF NOT EXISTS cat_tools; CREATE SCHEMA object_reference;