Skip to content

Commit

Permalink
Allow setting the excluded columns directly.
Browse files Browse the repository at this point in the history
  • Loading branch information
Vik Fearing committed Sep 14, 2019
1 parent a2b4f9e commit c151951
Show file tree
Hide file tree
Showing 5 changed files with 145 additions and 1 deletion.
11 changes: 10 additions & 1 deletion README.md
Original file line number Diff line number Diff line change
Expand Up @@ -248,10 +248,19 @@ a column would be in its own table, but if not then it can be excluded
with an optional parameter:

``` sql
SELECT periods.add_system_time_period('example',
SELECT periods.add_system_time_period(
'example',
excluded_column_names => ARRAY['foo', 'bar']);
```

Excluded columns can be define after the fact, as well.

``` sql
SELECT periods.set_system_time_period_excluded_columns(
'example',
ARRAY['foo', 'bar']);
```

This functionality is not present in the SQL standard.

## `WITH SYSTEM VERSIONING`
Expand Down
41 changes: 41 additions & 0 deletions expected/excluded_columns.out
Original file line number Diff line number Diff line change
Expand Up @@ -84,6 +84,47 @@ SELECT value, null_value, flap, system_time_start <> :'now2' AS changed FROM exc
howdy folks! | 0 | on | t
(1 row)

/* Test directly setting the excluded columns */
SELECT periods.drop_system_versioning('excl');
drop_system_versioning
------------------------
t
(1 row)

ALTER TABLE excl ADD COLUMN flop text;
ALTER TABLE excl_history ADD COLUMN flop text;
SELECT periods.add_system_versioning('excl');
add_system_versioning
-----------------------

(1 row)

SELECT periods.set_system_time_period_excluded_columns('excl', ARRAY['flap', 'flop']);
set_system_time_period_excluded_columns
-----------------------------------------

(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,flop}
(1 row)

UPDATE excl SET flop = 'flop';
SELECT value, null_value, flap, flop FROM excl;
value | null_value | flap | flop
--------------+------------+------+------
howdy folks! | 0 | on | flop
(1 row)

SELECT value, null_value, flap, flop FROM excl_history ORDER BY system_time_start;
value | null_value | flap | flop
--------------+------------+------+------
hello world | | on |
howdy folks! | | on |
(2 rows)

SELECT periods.drop_system_versioning('excl');
drop_system_versioning
------------------------
Expand Down
41 changes: 41 additions & 0 deletions expected/excluded_columns_1.out
Original file line number Diff line number Diff line change
Expand Up @@ -82,6 +82,47 @@ SELECT value, null_value, flap, system_time_start <> :'now2' AS changed FROM exc
howdy folks! | 0 | on | t
(1 row)

/* Test directly setting the excluded columns */
SELECT periods.drop_system_versioning('excl');
drop_system_versioning
------------------------
t
(1 row)

ALTER TABLE excl ADD COLUMN flop text;
ALTER TABLE excl_history ADD COLUMN flop text;
SELECT periods.add_system_versioning('excl');
add_system_versioning
-----------------------

(1 row)

SELECT periods.set_system_time_period_excluded_columns('excl', ARRAY['flap', 'flop']);
set_system_time_period_excluded_columns
-----------------------------------------

(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,flop}
(1 row)

UPDATE excl SET flop = 'flop';
SELECT value, null_value, flap, flop FROM excl;
value | null_value | flap | flop
--------------+------------+------+------
howdy folks! | 0 | on | flop
(1 row)

SELECT value, null_value, flap, flop FROM excl_history ORDER BY system_time_start;
value | null_value | flap | flop
--------------+------------+------+------
hello world | | on |
howdy folks! | | on |
(2 rows)

SELECT periods.drop_system_versioning('excl');
drop_system_versioning
------------------------
Expand Down
41 changes: 41 additions & 0 deletions periods--1.0--1.1.sql
Original file line number Diff line number Diff line change
Expand Up @@ -922,3 +922,44 @@ BEGIN
END;
$function$;

CREATE FUNCTION periods.set_system_time_period_excluded_columns(
table_name regclass,
excluded_column_names name[])
RETURNS void
LANGUAGE plpgsql
AS
$function$
#variable_conflict use_variable
DECLARE
excluded_column_name name;
BEGIN
/* Always serialize operations on our catalogs */
PERFORM periods._serialize(table_name);

/* 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_name, 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_name, u.name)
WHERE a.attnum < 0
LOOP
RAISE EXCEPTION 'cannot exclude system column "%"', excluded_column_name;
END LOOP;

/* Do it. */
UPDATE periods.system_time_periods AS stp SET
excluded_column_names = excluded_column_names
WHERE stp.table_name = table_name;
END;
$function$;
12 changes: 12 additions & 0 deletions sql/excluded_columns.sql
Original file line number Diff line number Diff line change
Expand Up @@ -36,6 +36,18 @@ SELECT value, null_value, flap, system_time_start <> :'now' AS changed FROM excl
UPDATE excl SET null_value = 0;
SELECT value, null_value, flap, system_time_start <> :'now2' AS changed FROM excl;

/* Test directly setting the excluded columns */
SELECT periods.drop_system_versioning('excl');
ALTER TABLE excl ADD COLUMN flop text;
ALTER TABLE excl_history ADD COLUMN flop text;
SELECT periods.add_system_versioning('excl');

SELECT periods.set_system_time_period_excluded_columns('excl', ARRAY['flap', 'flop']);
TABLE periods.system_time_periods;
UPDATE excl SET flop = 'flop';
SELECT value, null_value, flap, flop FROM excl;
SELECT value, null_value, flap, flop FROM excl_history ORDER BY system_time_start;

SELECT periods.drop_system_versioning('excl');
SELECT periods.drop_system_time_period('excl');
DROP TABLE excl;

0 comments on commit c151951

Please sign in to comment.