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

Detect view definition changes #40

Open
wants to merge 3 commits into
base: master
Choose a base branch
from
Open
Show file tree
Hide file tree
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
28 changes: 25 additions & 3 deletions src/view.c
Original file line number Diff line number Diff line change
Expand Up @@ -42,17 +42,17 @@ getViews(PGconn *c, int *n)
if (PQserverVersion(c) >= 90300)
{
res = PQexec(c,
"SELECT c.oid, n.nspname, c.relname, pg_get_viewdef(c.oid) AS viewdef, array_to_string(array_remove(array_remove(c.reloptions,'check_option=local'),'check_option=cascaded'), ', ') AS reloptions, CASE WHEN 'check_option=local' = ANY(c.reloptions) THEN 'LOCAL'::text WHEN 'check_option=cascaded' = ANY(c.reloptions) THEN 'CASCADED'::text ELSE NULL END AS checkoption, obj_description(c.oid, 'pg_class') AS description, pg_get_userbyid(c.relowner) AS relowner FROM pg_class c INNER JOIN pg_namespace n ON (c.relnamespace = n.oid) WHERE relkind = 'v' AND nspname !~ '^pg_' AND nspname <> 'information_schema' AND NOT EXISTS(SELECT 1 FROM pg_depend d WHERE c.oid = d.objid AND d.deptype = 'e') ORDER BY nspname, relname");
"SELECT c.oid, n.nspname, c.relname, pg_get_viewdef(c.oid) AS viewdef, array_to_string(array_remove(array_remove(c.reloptions,'check_option=local'),'check_option=cascaded'), ', ') AS reloptions, CASE WHEN 'check_option=local' = ANY(c.reloptions) THEN 'LOCAL'::text WHEN 'check_option=cascaded' = ANY(c.reloptions) THEN 'CASCADED'::text ELSE NULL END AS checkoption, obj_description(c.oid, 'pg_class') AS description, pg_get_userbyid(c.relowner) AS relowner, EXISTS(SELECT 1 FROM pg_depend d WHERE d.refobjid = c.oid AND d.deptype = 'n' AND NOT EXISTS(SELECT 1 FROM pg_depend d2 WHERE d2.refobjid = d.refobjid AND d2.objid = d.objid AND deptype IN ('i', 'a'))) AS has_dependants FROM pg_class c INNER JOIN pg_namespace n ON (c.relnamespace = n.oid) WHERE relkind = 'v' AND nspname !~ '^pg_' AND nspname <> 'information_schema' AND NOT EXISTS(SELECT 1 FROM pg_depend d WHERE c.oid = d.objid AND d.deptype = 'e') ORDER BY nspname, relname");
}
else if (PQserverVersion(c) >= 90100) /* extension support */
{
res = PQexec(c,
"SELECT c.oid, n.nspname, c.relname, pg_get_viewdef(c.oid) AS viewdef, array_to_string(c.reloptions, ', ') AS reloptions, CASE WHEN 'check_option=local' = ANY(c.reloptions) THEN 'LOCAL'::text WHEN 'check_option=cascaded' = ANY(c.reloptions) THEN 'CASCADED'::text ELSE NULL END AS checkoption, obj_description(c.oid, 'pg_class') AS description, pg_get_userbyid(c.relowner) AS relowner FROM pg_class c INNER JOIN pg_namespace n ON (c.relnamespace = n.oid) WHERE relkind = 'v' AND nspname !~ '^pg_' AND nspname <> 'information_schema' AND NOT EXISTS(SELECT 1 FROM pg_depend d WHERE c.oid = d.objid AND d.deptype = 'e') ORDER BY nspname, relname");
"SELECT c.oid, n.nspname, c.relname, pg_get_viewdef(c.oid) AS viewdef, array_to_string(c.reloptions, ', ') AS reloptions, CASE WHEN 'check_option=local' = ANY(c.reloptions) THEN 'LOCAL'::text WHEN 'check_option=cascaded' = ANY(c.reloptions) THEN 'CASCADED'::text ELSE NULL END AS checkoption, obj_description(c.oid, 'pg_class') AS description, pg_get_userbyid(c.relowner) AS relowner, EXISTS(SELECT 1 FROM pg_depend d WHERE d.refobjid = c.oid AND d.deptype = 'n' AND NOT EXISTS(SELECT 1 FROM pg_depend d2 WHERE d2.refobjid = d.refobjid AND d2.objid = d.objid AND deptype IN ('i', 'a'))) AS has_dependants FROM pg_class c INNER JOIN pg_namespace n ON (c.relnamespace = n.oid) WHERE relkind = 'v' AND nspname !~ '^pg_' AND nspname <> 'information_schema' AND NOT EXISTS(SELECT 1 FROM pg_depend d WHERE c.oid = d.objid AND d.deptype = 'e') ORDER BY nspname, relname");
}
else
{
res = PQexec(c,
"SELECT c.oid, n.nspname, c.relname, pg_get_viewdef(c.oid) AS viewdef, array_to_string(c.reloptions, ', ') AS reloptions, CASE WHEN 'check_option=local' = ANY(c.reloptions) THEN 'LOCAL'::text WHEN 'check_option=cascaded' = ANY(c.reloptions) THEN 'CASCADED'::text ELSE NULL END AS checkoption, obj_description(c.oid, 'pg_class') AS description, pg_get_userbyid(c.relowner) AS relowner FROM pg_class c INNER JOIN pg_namespace n ON (c.relnamespace = n.oid) WHERE relkind = 'v' AND nspname !~ '^pg_' AND nspname <> 'information_schema' ORDER BY nspname, relname");
"SELECT c.oid, n.nspname, c.relname, pg_get_viewdef(c.oid) AS viewdef, array_to_string(c.reloptions, ', ') AS reloptions, CASE WHEN 'check_option=local' = ANY(c.reloptions) THEN 'LOCAL'::text WHEN 'check_option=cascaded' = ANY(c.reloptions) THEN 'CASCADED'::text ELSE NULL END AS checkoption, obj_description(c.oid, 'pg_class') AS description, pg_get_userbyid(c.relowner) AS relowner, EXISTS(SELECT 1 FROM pg_depend d WHERE d.refobjid = c.oid AND d.deptype = 'n' AND NOT EXISTS(SELECT 1 FROM pg_depend d2 WHERE d2.refobjid = d.refobjid AND d2.objid = d.objid AND deptype IN ('i', 'a'))) AS has_dependants FROM pg_class c INNER JOIN pg_namespace n ON (c.relnamespace = n.oid) WHERE relkind = 'v' AND nspname !~ '^pg_' AND nspname <> 'information_schema' ORDER BY nspname, relname");
}

if (PQresultStatus(res) != PGRES_TUPLES_OK)
Expand Down Expand Up @@ -94,6 +94,8 @@ getViews(PGconn *c, int *n)

v[i].owner = strdup(PQgetvalue(res, i, PQfnumber(res, "relowner")));

v[i].has_dependants = (PQgetvalue(res, i, PQfnumber(res, "has_dependants"))[0] == 't');

/*
* Security labels are not assigned here (see getViewSecurityLabels),
* but default values are essential to avoid having trouble in
Expand Down Expand Up @@ -358,6 +360,26 @@ dumpAlterView(FILE *output, PQLView *a, PQLView *b)
}
}

/*
* Compare view definitions.
* Note: PostgreSQL 9.3 changed the way pg_get_viewdef(...) deals with indentation and line wrapping.
* This may result in false positives when comparing views using < 9.3 and >= 9.3.
*/
if (strcmp(a->viewdef, b->viewdef) != 0)
{
if (!a->has_dependants)
{
dumpDropView(output, a);
dumpCreateView(output, b);
}
else
{
logWarning("view \"%s\".\"%s\" changed definition, but cannot be replaced automatically; some other objects depend on it", a->obj.schemaname, a->obj.objectname);
fprintf(output, "\n\n");
fprintf(output, "-- view %s.%s changed definition;", a->obj.schemaname, a->obj.objectname);
}
}

/* comment */
if (options.comment)
{
Expand Down
2 changes: 2 additions & 0 deletions src/view.h
Original file line number Diff line number Diff line change
Expand Up @@ -22,6 +22,8 @@ typedef struct PQLView
char *comment;
char *owner;

bool has_dependants;

/* security labels */
PQLSecLabel *seclabels;
int nseclabels;
Expand Down
4 changes: 4 additions & 0 deletions test/from-view.sql
Original file line number Diff line number Diff line change
Expand Up @@ -3,3 +3,7 @@ CREATE VIEW same_view_1 AS SELECT prod_id, title, price FROM products WHERE comm
CREATE VIEW same_view_2 AS SELECT orderdate, COUNT(*) AS total_day FROM orders GROUP BY orderdate;

ALTER VIEW same_view_2 SET (security_barrier=on);

CREATE VIEW same_view_3 AS SELECT orderdate, COUNT(*) AS total_day FROM orders GROUP BY orderdate;

-- CREATE VIEW same_view_4 AS SELECT * FROM same_view_3;
2 changes: 2 additions & 0 deletions test/to-view.sql
Original file line number Diff line number Diff line change
Expand Up @@ -3,3 +3,5 @@ CREATE VIEW same_view_1 AS SELECT prod_id, title, price FROM products WHERE comm
ALTER VIEW same_view_1 SET (security_barrier=on, check_option=cascaded);

CREATE VIEW same_view_2 AS SELECT orderdate, COUNT(*) AS total_day FROM orders GROUP BY orderdate;

CREATE VIEW same_view_3 AS SELECT orderdate, COUNT(*) AS totals_by_day FROM orders GROUP BY orderdate;