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

checks for comments, exclusion constraints, array set_eq, and rls #306

Draft
wants to merge 3 commits into
base: main
Choose a base branch
from
Draft
Show file tree
Hide file tree
Changes from 1 commit
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
121 changes: 117 additions & 4 deletions doc/pgtap.mmd
Original file line number Diff line number Diff line change
Expand Up @@ -1378,10 +1378,12 @@ same!

### `set_eq()` ###

SELECT set_eq( :sql, :sql, :description );
SELECT set_eq( :sql, :sql );
SELECT set_eq( :sql, :array, :description );
SELECT set_eq( :sql, :array );
SELECT set_eq( :sql, :sql, :description );
SELECT set_eq( :sql, :sql );
SELECT set_eq( :sql, :array, :description );
SELECT set_eq( :sql, :array );
SELECT set_eq( :array, :array, :description );
SELECT set_eq( :array, :array );

**Parameters**

Expand Down Expand Up @@ -5068,6 +5070,30 @@ that do have check constraints, if any:
Just like `col_is_pk()`, except that it test that the column or array of
columns have a check constraint on them.

### `col_has_exclusion()` ###

SELECT col_has_check( :schema, :table, :columns, :description );

**Parameters**

`:schema`
: Schema in which to find the table.

`:table`
: Name of a table containing the exclusion constraint.

`:columns`
: Array of the names of the exclusion constraint columns.

`:column`
: Name of the exclusion constraint column.

`:description`
: A short description of the test.

Just like `col_is_check()`, except that it test that the column array has
dmfay marked this conversation as resolved.
Show resolved Hide resolved
an exclusion constraint on them.

### `index_is_unique()` ###

SELECT index_is_unique( :schema, :table, :index, :description );
Expand Down Expand Up @@ -7960,6 +7986,93 @@ missing policy command, like so:
# have: INSERT
# want: ALL

### `rls_is_enabled()` ###

SELECT rls_is_enabled( :schema, :table, :desired_value );

Test whether [row-level security](https://www.postgresql.org/docs/current/ddl-rowsecurity.html)
is enabled (`:desired_value` true) or disabled (`:desired_value` false).
Comment on lines +7993 to +7994
Copy link
Owner

Choose a reason for hiding this comment

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

The description should go after the parameters to be consistent with the existing docs. Same goes for some of the other documentation added here.


**Parameters**

`:schema`
: Name of a schema in which to find the `:table`.

`:table`
: Name of a table which has RLS enabled or not.

`:desired_value`
: `true` to assert that the table has RLS enabled, `false` to assert it's disabled.

Commentary
----------

### `table_comment_has()` ###

SELECT table_comment_has( :schema, :table, :comment );
SELECT table_comment_has( :schema, :table, :comment, :description );

Assert that a table comment contains a full line of text (delimited by `\n`).

**Parameters**

`:schema`
: Name of a schema in which to find the `:table`.

`:table`
: Name of a table which has a comment set.

`:comment`
: The line the table comment should include.

`:description`
: A short description of the test.

### `column_comment_has()` ###

SELECT column_comment_has( :schema, :table, :column, :comment );
SELECT column_comment_has( :schema, :table, :column, :comment, :description );

Assert that a comment comment contains a full line of text (delimited by `\n`).

**Parameters**

`:schema`
: Name of a schema in which to find the `:table`.

`:table`
: Name of a table including `:column`.

`:column`
: Name of a column which has a comment set.

`:comment`
: The line the column comment should include.

`:description`
: A short description of the test.

### `function_comment_has()` ###

SELECT function_comment_has( :schema, :function, :comment );
SELECT function_comment_has( :schema, :function, :comment, :description );

Assert that a function comment contains a full line of text (delimited by `\n`).

**Parameters**

`:schema`
: Name of a schema in which to find the `:function`.

`:function`
: Name of a function which has RLS enabled or not.

`:comment`
: The line the function comment should include.

`:description`
: A short description of the test.

No Test for the Wicked
======================

Expand Down
86 changes: 86 additions & 0 deletions sql/pgtap--1.2.0--1.2.1.sql
Original file line number Diff line number Diff line change
Expand Up @@ -155,3 +155,89 @@ CREATE OR REPLACE FUNCTION col_is_pk ( NAME, NAME, NAME )
RETURNS TEXT AS $$
SELECT col_is_pk( $1, $2, $3, 'Column ' || quote_ident($1) || '.' || quote_ident($2) || '(' || quote_ident($3) || ') should be a primary key' );
$$ LANGUAGE sql;

-- col_has_exclusion(schema, table, columns, description)
CREATE OR REPLACE FUNCTION col_has_exclusion(TEXT, TEXT, TEXT[], TEXT)
RETURNS TEXT AS $$
SELECT ok(array_agg(attr.attname)::TEXT[] @> $3 AND $3 @> array_agg(attr.attname)::TEXT[])
FROM pg_constraint AS con
JOIN LATERAL unnest(con.conkey) AS attnums (num) ON TRUE
JOIN pg_attribute AS attr ON attr.attrelid = con.conrelid
AND attr.attnum = attnums.num
WHERE conrelid = format('%1$I.%2$I', $1, $2)::regclass
AND contype = 'x';
$$ LANGUAGE sql;

-- set_eq( array, array, description )
CREATE OR REPLACE FUNCTION set_eq(anyarray, anyarray, TEXT)
RETURNS TEXT AS $$
SELECT ok($1 @> $2 AND $2 @> $1, $3);
$$ LANGUAGE sql;

-- set_eq( array, array )
CREATE OR REPLACE FUNCTION set_eq(anyarray, anyarray)
RETURNS TEXT AS $$
SELECT set_eq($1, $2, 'arrays have identical contents')
$$ LANGUAGE sql;

-- table_comment_has(schema, table, comment, description)
CREATE OR REPLACE FUNCTION table_comment_has(TEXT, TEXT, TEXT, TEXT)
RETURNS TEXT AS $$
SELECT ok(COUNT(*) >= 1, $4)
FROM pg_description
JOIN LATERAL regexp_split_to_table(description, '\n') AS lines (line) ON TRUE
WHERE objoid = format('%1$I.%2$I', $1, $2)::regclass
AND objsubid = 0
AND trim(line) ILIKE $3
$$ LANGUAGE sql;

-- table_comment_has(schema, table, comment)
CREATE OR REPLACE FUNCTION table_comment_has(TEXT, TEXT, TEXT)
RETURNS TEXT AS $$
SELECT table_comment_has($1, $2, $3, 'table comment contains expected line');
$$ LANGUAGE sql;

-- column_comment_has(schema, table, column, comment, description)
CREATE OR REPLACE FUNCTION column_comment_has(TEXT, TEXT, TEXT, TEXT, TEXT)
RETURNS TEXT AS $$
SELECT ok(COUNT(*) >= 1, $5)
FROM pg_description
JOIN pg_attribute AS attr
ON attr.attrelid = pg_description.objoid
AND attr.attnum = pg_description.objsubid
JOIN LATERAL regexp_split_to_table(description, '\n') AS lines (line) ON TRUE
WHERE objoid = format('%1$I.%2$I', $1, $2)::regclass
AND attr.attname = $3::name
AND trim(line) ILIKE $4
$$ LANGUAGE sql;

-- column_comment_has(schema, table, column, comment)
CREATE OR REPLACE FUNCTION column_comment_has(TEXT, TEXT, TEXT, TEXT)
RETURNS TEXT AS $$
SELECT column_comment_has($1, $2, $3, $4, 'column comment contains expected line');
$$ LANGUAGE sql;

-- function_comment_has(schema, function, comment, description)
CREATE OR REPLACE FUNCTION function_comment_has(TEXT, TEXT, TEXT, TEXT)
RETURNS TEXT AS $$
SELECT ok(COUNT(*) >= 1, $4)
FROM pg_description
JOIN LATERAL regexp_split_to_table(description, '\n') AS lines (line) ON TRUE
WHERE objoid = format('%1$I.%2$I', $1, $2)::regproc
AND objsubid = 0
AND trim(line) ILIKE $3
$$ LANGUAGE sql;

-- function_comment_has(schema, function, comment)
CREATE OR REPLACE FUNCTION function_comment_has(TEXT, TEXT, TEXT)
RETURNS TEXT AS $$
SELECT function_comment_has($1, $2, $3, 'function comment contains expected line');
$$ LANGUAGE sql;

-- rls_is_enabled(schema, table, desired_value)
CREATE OR REPLACE FUNCTION rls_is_enabled(TEXT, TEXT, BOOLEAN)
RETURNS TEXT AS $$
SELECT ok(relrowsecurity IS NOT DISTINCT FROM $3)
FROM pg_class
WHERE oid = format('%1$I.%2$I', $1, $2)::regclass
$$ LANGUAGE sql;
86 changes: 86 additions & 0 deletions sql/pgtap.sql.in
Original file line number Diff line number Diff line change
Expand Up @@ -2418,6 +2418,18 @@ RETURNS TEXT AS $$
SELECT col_has_check( $1, $2, 'Column ' || quote_ident($1) || '(' || quote_ident($2) || ') should have a check constraint' );
$$ LANGUAGE sql;

-- col_has_exclusion(schema, table, columns, description)
CREATE OR REPLACE FUNCTION col_has_exclusion(TEXT, TEXT, TEXT[], TEXT)
RETURNS TEXT AS $$
SELECT ok(array_agg(attr.attname)::TEXT[] @> $3 AND $3 @> array_agg(attr.attname)::TEXT[])
Copy link
Owner

Choose a reason for hiding this comment

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

Looks like the @> operator will work on Postgres 9.1. Would you add tests for these new functions?

FROM pg_constraint AS con
JOIN LATERAL unnest(con.conkey) AS attnums (num) ON TRUE
JOIN pg_attribute AS attr ON attr.attrelid = con.conrelid
AND attr.attnum = attnums.num
WHERE conrelid = format('%1$I.%2$I', $1, $2)::regclass
AND contype = 'x';
$$ LANGUAGE sql;

-- fk_ok( fk_schema, fk_table, fk_column[], pk_schema, pk_table, pk_column[], description )
CREATE OR REPLACE FUNCTION fk_ok ( NAME, NAME, NAME[], NAME, NAME, NAME[], TEXT )
RETURNS TEXT AS $$
Expand Down Expand Up @@ -6864,6 +6876,18 @@ RETURNS TEXT AS $$
SELECT _relcomp( $1, $2, NULL::text, '' );
$$ LANGUAGE sql;

-- set_eq( array, array, description )
CREATE OR REPLACE FUNCTION set_eq(anyarray, anyarray, TEXT)
RETURNS TEXT AS $$
SELECT ok($1 @> $2 AND $2 @> $1, $3);
Copy link
Owner

Choose a reason for hiding this comment

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

This seems superfluous. Why not just use is(array1, array2)?

Copy link
Author

Choose a reason for hiding this comment

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

is(a1, a2) is order-dependent but the order of our arrays is not guaranteed. Is there something else that would suit, short of unnesting both sides?

Copy link
Owner

Choose a reason for hiding this comment

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

Oh, I hadn't thought of that, of course! I like it! Would be useful to have something in the docs that talks about that difference.

$$ LANGUAGE sql;

-- set_eq( array, array )
CREATE OR REPLACE FUNCTION set_eq(anyarray, anyarray)
RETURNS TEXT AS $$
SELECT set_eq($1, $2, 'arrays have identical contents')
$$ LANGUAGE sql;

-- bag_eq( sql, sql, description )
CREATE OR REPLACE FUNCTION bag_eq( TEXT, TEXT, TEXT )
RETURNS TEXT AS $$
Expand Down Expand Up @@ -11366,3 +11390,65 @@ RETURNS TEXT AS $$
'Function ' || quote_ident($1) || '() should not be a procedure'
);
$$ LANGUAGE sql;

-- table_comment_has(schema, table, comment, description)
CREATE OR REPLACE FUNCTION table_comment_has(TEXT, TEXT, TEXT, TEXT)
Copy link
Owner

Choose a reason for hiding this comment

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

WE use _has more to indicate that a database has an object, like a table. I think a better term to use here would be _contains. Or perhaps _matches and use a regular expression? That could help avoid variations in line endings across platforms.

RETURNS TEXT AS $$
SELECT ok(COUNT(*) >= 1, $4)
FROM pg_description
JOIN LATERAL regexp_split_to_table(description, '\n') AS lines (line) ON TRUE
WHERE objoid = format('%1$I.%2$I', $1, $2)::regclass
AND objsubid = 0
AND trim(line) ILIKE $3
$$ LANGUAGE sql;

-- table_comment_has(schema, table, comment)
CREATE OR REPLACE FUNCTION table_comment_has(TEXT, TEXT, TEXT)
RETURNS TEXT AS $$
SELECT table_comment_has($1, $2, $3, 'table comment contains expected line');
$$ LANGUAGE sql;

-- column_comment_has(schema, table, column, comment, description)
CREATE OR REPLACE FUNCTION column_comment_has(TEXT, TEXT, TEXT, TEXT, TEXT)
RETURNS TEXT AS $$
SELECT ok(COUNT(*) >= 1, $5)
FROM pg_description
JOIN pg_attribute AS attr
ON attr.attrelid = pg_description.objoid
AND attr.attnum = pg_description.objsubid
JOIN LATERAL regexp_split_to_table(description, '\n') AS lines (line) ON TRUE
WHERE objoid = format('%1$I.%2$I', $1, $2)::regclass
AND attr.attname = $3::name
AND trim(line) ILIKE $4
$$ LANGUAGE sql;

-- column_comment_has(schema, table, column, comment)
CREATE OR REPLACE FUNCTION column_comment_has(TEXT, TEXT, TEXT, TEXT)
RETURNS TEXT AS $$
SELECT column_comment_has($1, $2, $3, $4, 'column comment contains expected line');
$$ LANGUAGE sql;

-- function_comment_has(schema, function, comment, description)
CREATE OR REPLACE FUNCTION function_comment_has(TEXT, TEXT, TEXT, TEXT)
RETURNS TEXT AS $$
SELECT ok(COUNT(*) >= 1, $4)
FROM pg_description
JOIN LATERAL regexp_split_to_table(description, '\n') AS lines (line) ON TRUE
WHERE objoid = format('%1$I.%2$I', $1, $2)::regproc
AND objsubid = 0
AND trim(line) ILIKE $3
$$ LANGUAGE sql;

-- function_comment_has(schema, function, comment)
CREATE OR REPLACE FUNCTION function_comment_has(TEXT, TEXT, TEXT)
RETURNS TEXT AS $$
SELECT function_comment_has($1, $2, $3, 'function comment contains expected line');
$$ LANGUAGE sql;

-- rls_is_enabled(schema, table, desired_value)
CREATE OR REPLACE FUNCTION rls_is_enabled(TEXT, TEXT, BOOLEAN)
RETURNS TEXT AS $$
SELECT ok(relrowsecurity IS NOT DISTINCT FROM $3)
FROM pg_class
WHERE oid = format('%1$I.%2$I', $1, $2)::regclass
$$ LANGUAGE sql;