Skip to content

Commit

Permalink
Prevent excluding system and non-existent columns.
Browse files Browse the repository at this point in the history
  • Loading branch information
Vik Fearing committed Sep 14, 2019
1 parent 44859c0 commit a2b4f9e
Show file tree
Hide file tree
Showing 6 changed files with 143 additions and 5 deletions.
15 changes: 14 additions & 1 deletion expected/excluded_columns.out
Original file line number Diff line number Diff line change
@@ -1,9 +1,22 @@
SELECT setting::integer < 90600 AS pre_96
FROM pg_settings WHERE name = 'server_version_num';
pre_96
--------
f
(1 row)

CREATE TABLE excl (
value text NOT NULL,
null_value integer,
flap text NOT NULL
);
SELECT periods.add_system_time_period('excl', excluded_column_names => ARRAY['flap']);
SELECT periods.add_system_time_period('excl', excluded_column_names => ARRAY['xmin']); -- fails
ERROR: cannot exclude system column "xmin"
CONTEXT: PL/pgSQL function periods.add_system_time_period(regclass,name,name,name,name,name,name,name,name[]) line 316 at RAISE
SELECT periods.add_system_time_period('excl', excluded_column_names => ARRAY['none']); -- fails
ERROR: column "none" does not exist
CONTEXT: PL/pgSQL function periods.add_system_time_period(regclass,name,name,name,name,name,name,name,name[]) line 306 at RAISE
SELECT periods.add_system_time_period('excl', excluded_column_names => ARRAY['flap']); -- passes
add_system_time_period
------------------------
t
Expand Down
97 changes: 97 additions & 0 deletions expected/excluded_columns_1.out
Original file line number Diff line number Diff line change
@@ -0,0 +1,97 @@
SELECT setting::integer < 90600 AS pre_96
FROM pg_settings WHERE name = 'server_version_num';
pre_96
--------
t
(1 row)

CREATE TABLE excl (
value text NOT NULL,
null_value integer,
flap text NOT NULL
);
SELECT periods.add_system_time_period('excl', excluded_column_names => ARRAY['xmin']); -- fails
ERROR: cannot exclude system column "xmin"
SELECT periods.add_system_time_period('excl', excluded_column_names => ARRAY['none']); -- fails
ERROR: column "none" does not exist
SELECT periods.add_system_time_period('excl', excluded_column_names => ARRAY['flap']); -- passes
add_system_time_period
------------------------
t
(1 row)

SELECT periods.add_system_versioning('excl');
NOTICE: history table "excl_history" created for "excl", be sure to index it properly
add_system_versioning
-----------------------

(1 row)

TABLE periods.periods;
table_name | period_name | start_column_name | end_column_name | range_type | bounds_check_constraint
------------+-------------+-------------------+-----------------+------------+-------------------------
excl | system_time | system_time_start | system_time_end | tstzrange | excl_system_time_check
(1 row)

TABLE periods.system_time_periods;
table_name | period_name | infinity_check_constraint | generated_always_trigger | write_history_trigger | truncate_trigger | excluded_column_names
------------+-------------+-------------------------------------+-----------------------------------+--------------------------------+------------------+-----------------------
excl | system_time | excl_system_time_end_infinity_check | excl_system_time_generated_always | excl_system_time_write_history | excl_truncate | {flap}
(1 row)

TABLE periods.system_versioning;
table_name | period_name | history_table_name | view_name | func_as_of | func_between | func_between_symmetric | func_from_to
------------+-------------+--------------------+-------------------+---------------------------------------+------------------------------------------------------------------+----------------------------------------------------------------------------+------------------------------------------------------------------
excl | system_time | excl_history | excl_with_history | excl__as_of(timestamp with time zone) | excl__between(timestamp with time zone,timestamp with time zone) | excl__between_symmetric(timestamp with time zone,timestamp with time zone) | excl__from_to(timestamp with time zone,timestamp with time zone)
(1 row)

BEGIN;
SELECT CURRENT_TIMESTAMP AS now \gset
INSERT INTO excl (value, flap) VALUES ('hello world', 'off');
COMMIT;
SELECT value, null_value, flap, system_time_start <> :'now' AS changed FROM excl;
value | null_value | flap | changed
-------------+------------+------+---------
hello world | | off | f
(1 row)

UPDATE excl SET flap = 'off';
UPDATE excl SET flap = 'on';
UPDATE excl SET flap = 'off';
UPDATE excl SET flap = 'on';
SELECT value, null_value, flap, system_time_start <> :'now' AS changed FROM excl;
value | null_value | flap | changed
-------------+------------+------+---------
hello world | | on | f
(1 row)

BEGIN;
SELECT CURRENT_TIMESTAMP AS now2 \gset
UPDATE excl SET value = 'howdy folks!';
COMMIT;
SELECT value, null_value, flap, system_time_start <> :'now' AS changed FROM excl;
value | null_value | flap | changed
--------------+------------+------+---------
howdy folks! | | on | t
(1 row)

UPDATE excl SET null_value = 0;
SELECT value, null_value, flap, system_time_start <> :'now2' AS changed FROM excl;
value | null_value | flap | changed
--------------+------------+------+---------
howdy folks! | 0 | on | t
(1 row)

SELECT periods.drop_system_versioning('excl');
drop_system_versioning
------------------------
t
(1 row)

SELECT periods.drop_system_time_period('excl');
drop_system_time_period
-------------------------
t
(1 row)

DROP TABLE excl;
2 changes: 1 addition & 1 deletion expected/health_checks.out
Original file line number Diff line number Diff line change
Expand Up @@ -12,7 +12,7 @@ ERROR: table "log" must be persistent
CONTEXT: PL/pgSQL function periods.add_period(regclass,name,name,name,regtype,name) line 72 at RAISE
SELECT periods.add_system_time_period('log'); -- fails
ERROR: table "log" must be persistent
CONTEXT: PL/pgSQL function periods.add_system_time_period(regclass,name,name,name,name,name,name,name,name[]) line 72 at RAISE
CONTEXT: PL/pgSQL function periods.add_system_time_period(regclass,name,name,name,name,name,name,name,name[]) line 74 at RAISE
ALTER TABLE log SET LOGGED;
SELECT periods.add_period('log', 'p', 's', 'e'); -- passes
add_period
Expand Down
4 changes: 2 additions & 2 deletions expected/system_time_periods.out
Original file line number Diff line number Diff line change
Expand Up @@ -222,7 +222,7 @@ SELECT periods.add_unique_key('no_unique', ARRAY['system_time_end'], 'p'); -- pa

SELECT periods.add_system_time_period('no_unique'); -- fails
ERROR: columns in period for SYSTEM_TIME are not allowed in UNIQUE keys
CONTEXT: PL/pgSQL function periods.add_system_time_period(regclass,name,name,name,name,name,name,name,name[]) line 46 at RAISE
CONTEXT: PL/pgSQL function periods.add_system_time_period(regclass,name,name,name,name,name,name,name,name[]) line 48 at RAISE
SELECT periods.drop_unique_key('no_unique', 'no_unique_system_time_start_p');
drop_unique_key
-----------------
Expand Down Expand Up @@ -278,5 +278,5 @@ SELECT periods.add_foreign_key('no_unique_ref', ARRAY['system_time_end'], 'q', '

SELECT periods.add_system_time_period('no_unique_ref'); -- fails
ERROR: columns for SYSTEM_TIME must not be part of foreign keys
CONTEXT: PL/pgSQL function periods.add_system_time_period(regclass,name,name,name,name,name,name,name,name[]) line 166 at RAISE
CONTEXT: PL/pgSQL function periods.add_system_time_period(regclass,name,name,name,name,name,name,name,name[]) line 168 at RAISE
DROP TABLE no_unique, no_unique_ref;
23 changes: 23 additions & 0 deletions periods--1.0--1.1.sql
Original file line number Diff line number Diff line change
Expand Up @@ -37,6 +37,8 @@ DECLARE
end_collation oid;
end_notnull boolean;

excluded_column_name name;

DATE_OID CONSTANT integer := 1082;
TIMESTAMP_OID CONSTANT integer := 1114;
TIMESTAMPTZ_OID CONSTANT integer := 1184;
Expand Down Expand Up @@ -311,6 +313,27 @@ BEGIN
END IF;
END IF;

/* Make sure all the excluded columns exist */
FOR excluded_column_name IN
SELECT u.name
FROM unnest(excluded_column_names) AS u (name)
WHERE NOT EXISTS (
SELECT FROM pg_catalog.pg_attribute AS a
WHERE (a.attrelid, a.attname) = (table_class, u.name))
LOOP
RAISE EXCEPTION 'column "%" does not exist', excluded_column_name;
END LOOP;

/* Don't allow system columns to be excluded either */
FOR excluded_column_name IN
SELECT u.name
FROM unnest(excluded_column_names) AS u (name)
JOIN pg_catalog.pg_attribute AS a ON (a.attrelid, a.attname) = (table_class, u.name)
WHERE a.attnum < 0
LOOP
RAISE EXCEPTION 'cannot exclude system column "%"', excluded_column_name;
END LOOP;

generated_always_trigger := coalesce(
generated_always_trigger,
periods._choose_name(ARRAY[table_name], 'system_time_generated_always'));
Expand Down
7 changes: 6 additions & 1 deletion sql/excluded_columns.sql
Original file line number Diff line number Diff line change
@@ -1,9 +1,14 @@
SELECT setting::integer < 90600 AS pre_96
FROM pg_settings WHERE name = 'server_version_num';

CREATE TABLE excl (
value text NOT NULL,
null_value integer,
flap text NOT NULL
);
SELECT periods.add_system_time_period('excl', excluded_column_names => ARRAY['flap']);
SELECT periods.add_system_time_period('excl', excluded_column_names => ARRAY['xmin']); -- fails
SELECT periods.add_system_time_period('excl', excluded_column_names => ARRAY['none']); -- fails
SELECT periods.add_system_time_period('excl', excluded_column_names => ARRAY['flap']); -- passes
SELECT periods.add_system_versioning('excl');

TABLE periods.periods;
Expand Down

0 comments on commit a2b4f9e

Please sign in to comment.