Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Working fully qualified table name and tables in different schema from function #4

Merged
merged 2 commits into from
Feb 10, 2018
Merged
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
30 changes: 23 additions & 7 deletions versioning_function.sql
Original file line number Diff line number Diff line change
Expand Up @@ -11,6 +11,7 @@ DECLARE
existing_range tstzrange;
holder record;
holder2 record;
pg_version integer;
BEGIN
-- version 0.0.1

Expand All @@ -34,7 +35,7 @@ BEGIN
history_table := TG_ARGV[1];

-- check if sys_period exists on original table
SELECT atttypid, attndims INTO holder FROM pg_attribute WHERE attrelid = TG_TABLE_NAME::regclass AND attname = sys_period AND NOT attisdropped;
SELECT atttypid, attndims INTO holder FROM pg_attribute WHERE attrelid = TG_RELID AND attname = sys_period AND NOT attisdropped;
Copy link
Contributor Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

TG_TABLE_NAME isn't enough as it doesn't specify schema.

Copy link
Contributor

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

I also noticed that if I used quoted identifiers, such as "Users", TG_TABLE_NAME would be users (lower cased). This would give the error: column "%" of relation "%" does not exist'

This change (and using it elsewhere) appears to fix that for the source table, but not for the history table. I haven't made any changes, yet, to see if I could fix the history table, also.

It's not a big deal, but it is an issue since I'm just starting out with postgres. I have since gone to the standard of lower case and underscores (or, at least, non-quoted identifiers).

IF NOT FOUND THEN
RAISE 'column "%" of relation "%" does not exist', sys_period, TG_TABLE_NAME USING
ERRCODE = 'undefined_column';
Expand Down Expand Up @@ -67,9 +68,19 @@ BEGIN
RETURN NEW;
END IF;

-- check if history table exits
IF to_regclass(history_table) IS NULL THEN
RAISE 'relation "%" does not exist', history_table;
SELECT current_setting('server_version_num')::integer
INTO pg_version;

-- to support postgres < 9.6
IF pg_version < 90600 THEN
-- check if history table exits
IF to_regclass(history_table::cstring) IS NULL THEN
RAISE 'relation "%" does not exist', history_table;
END IF;
ELSE
IF to_regclass(history_table) IS NULL THEN
RAISE 'relation "%" does not exist', history_table;
END IF;
END IF;

-- check if history table has sys_period
Expand Down Expand Up @@ -108,7 +119,7 @@ BEGIN
main AS
(SELECT attname, atttypid
FROM pg_attribute
WHERE attrelid = TG_TABLE_NAME::regclass
WHERE attrelid = TG_RELID
AND attnum > 0
AND NOT attisdropped)
SELECT
Expand Down Expand Up @@ -138,7 +149,7 @@ BEGIN
main AS
(SELECT attname
FROM pg_attribute
WHERE attrelid = TG_TABLE_NAME::regclass
WHERE attrelid = TG_RELID
AND attnum > 0
AND NOT attisdropped)
SELECT array_agg(quote_ident(history.attname)) INTO commonColumns
Expand All @@ -148,7 +159,12 @@ BEGIN
AND history.attname != sys_period;

EXECUTE ('INSERT INTO ' ||
quote_ident(history_table) ||
CASE split_part(history_table, '.', 2)
Copy link
Contributor Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Using a fully qualified name as the history table should be supported - it is in the extension version.

Copy link
Contributor Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

This was necessary because of this error (simplified):

ERROR:  relation "schema_name.table_history" does not exist at character 13
QUERY:  INSERT INTO "schema_name.table_history"(table_id,valid_between) VALUES ($1.table_id,tstzrange($2, $3, '[)'))
CONTEXT:  PL/pgSQL function versioning() line 149 at EXECUTE

WHEN '' THEN
quote_ident(history_table)
ELSE
quote_ident(split_part(history_table, '.', 1)) || '.' || quote_ident(split_part(history_table, '.', 2))
END ||
'(' ||
array_to_string(commonColumns , ',') ||
',' ||
Expand Down