If there are view dependencies on a table you must use the CASCADE
keyword to drop it. Also, you cannot alter the table if there are view dependencies on it. This example shows a view dependency on a table.
CREATE TABLE t (id integer PRIMARY KEY);
CREATE VIEW v AS SELECT * FROM t;
DROP TABLE t;
ERROR: cannot drop table t because other objects depend on it
DETAIL: view v depends on table t
HINT: Use DROP ... CASCADE to drop the dependent objects too.
ALTER TABLE t DROP id;
ERROR: cannot drop column id of table t because other objects depend on it
DETAIL: view v depends on column id of table t
HINT: Use DROP ... CASCADE to drop the dependent objects too.
As the previous example shows, altering a table can be quite a challenge if there is a deep hierarchy of views, because you have to create the views in the correct order. You cannot create a view unless all the objects it requires are present.
You can use view dependency information when you want to alter a table that is referenced by a view. For example, you might want to change a table’s column data type from integer
to bigint
because you realize you need to store larger numbers. However, you cannot do that if there are views that use the column. You first have to drop those views, then change the column and then run all the CREATE VIEW
statements to create the views again.
Finding View Dependencies
The following example queries list view information on dependencies on tables and columns.
- Finding Direct View Dependencies on a Table
- Finding Direct Dependencies on a Table Column
- Listing View Schemas
- Listing View Definitions
- Listing Nested Views
The example output is based on the Example Data at the end of this topic.
Also, you can use the first example query Finding Direct View Dependencies on a Table to find dependencies on user-defined functions (or procedures). The query uses the catalog table pg_class
that contains information about tables and views. For functions, you can use the catalog table pg_proc to get information about functions.
For detailed information about the system catalog tables that store view information, see About View Storage in Greenplum Database.
Finding Direct View Dependencies on a Table
To find out which views directly depend on table t1
, create a query that performs a join among the catalog tables that contain the dependency information, and qualify the query to return only view dependencies.
SELECT v.oid::regclass AS view,
d.refobjid::regclass AS ref_object -- name of table
-- d.refobjid::regproc AS ref_object -- name of function
FROM pg_depend AS d -- objects that depend on a table
JOIN pg_rewrite AS r -- rules depending on a table
ON r.oid = d.objid
JOIN pg_class AS v -- views for the rules
ON v.oid = r.ev_class
WHERE v.relkind = 'v' -- filter views only
-- dependency must be a rule depending on a relation
AND d.classid = 'pg_rewrite'::regclass
AND d.deptype = 'n' -- normal dependency
-- qualify object
AND d.refclassid = 'pg_class'::regclass -- dependent table
AND d.refobjid = 't1'::regclass
-- AND d.refclassid = 'pg_proc'::regclass -- dependent function
-- AND d.refobjid = 'f'::regproc
;
view | ref_object
------------+------------
v1 | t1
v2 | t1
v2 | t1
v3 | t1
mytest.vt1 | t1
mytest.v2a | t1
mytest.v2a | t1
(7 rows)
The query performs casts to the regclass
object identifier type. For information about object identifier types, see the PostgeSQL documentation on Object Identifier Types.
In some cases, the views are listed multiple times because the view references multiple table columns. You can remove those duplicates using DISTINCT
.
You can alter the query to find views with direct dependencies on the function f
.
- In the
SELECT
clause replace the name of the tabled.refobjid::regclass as ref_object
with the name of the functiond.refobjid::regproc as ref_object
- In the
WHERE
clause replace the catalog of the referenced object fromd.refclassid = 'pg_class'::regclass
for tables, tod.refclassid = 'pg_proc'::regclass
for procedures (functions). Also change the object name fromd.refobjid = 't1'::regclass
tod.refobjid = 'f'::regproc
- In the
WHERE
clause, replace the name of the tablerefobjid = 't1'::regclass
with the name of the functionrefobjid = 'f'::regproc
.
In the example query, the changes have been commented out (prefixed with --
). You can comment out the lines for the table and enable the lines for the function.
Finding Direct Dependencies on a Table Column
You can modify the previous query to find those views that depend on a certain table column, which can be useful if you are planning to drop a column (adding a column to the base table is never a problem). The query uses the table column information in the pg_attribute catalog table.
This query finds the views that depend on the column id
of table t1
:
SELECT v.oid::regclass AS view,
d.refobjid::regclass AS ref_object, -- name of table
a.attname AS col_name -- column name
FROM pg_attribute AS a -- columns for a table
JOIN pg_depend AS d -- objects that depend on a column
ON d.refobjsubid = a.attnum AND d.refobjid = a.attrelid
JOIN pg_rewrite AS r -- rules depending on the column
ON r.oid = d.objid
JOIN pg_class AS v -- views for the rules
ON v.oid = r.ev_class
WHERE v.relkind = 'v' -- filter views only
-- dependency must be a rule depending on a relation
AND d.classid = 'pg_rewrite'::regclass
AND d.refclassid = 'pg_class'::regclass
AND d.deptype = 'n' -- normal dependency
AND a.attrelid = 't1'::regclass
AND a.attname = 'id'
;
view | ref_object | col_name
------------+------------+----------
v1 | t1 | id
v2 | t1 | id
mytest.vt1 | t1 | id
mytest.v2a | t1 | id
(4 rows)
Listing View Schemas
If you have created views in multiple schemas, you can also list views, each view’s schema, and the table referenced by the view. The query retrieves the schema from the catalog table pg_namespace
and excludes the system schemas pg_catalog
, information_schema
, and gp_toolkit
. Also, the query does not list a view if the view refers to itself.
SELECT v.oid::regclass AS view,
ns.nspname AS schema, -- view schema,
d.refobjid::regclass AS ref_object -- name of table
FROM pg_depend AS d -- objects that depend on a table
JOIN pg_rewrite AS r -- rules depending on a table
ON r.oid = d.objid
JOIN pg_class AS v -- views for the rules
ON v.oid = r.ev_class
JOIN pg_namespace AS ns -- schema information
ON ns.oid = v.relnamespace
WHERE v.relkind = 'v' -- filter views only
-- dependency must be a rule depending on a relation
AND d.classid = 'pg_rewrite'::regclass
AND d.refclassid = 'pg_class'::regclass -- referenced objects in pg_class -- tables and views
AND d.deptype = 'n' -- normal dependency
-- qualify object
AND ns.nspname NOT IN ('pg_catalog', 'information_schema', 'gp_toolkit') -- system schemas
AND NOT (v.oid = d.refobjid) -- not self-referencing dependency
;
view | schema | ref_object
------------+--------+------------
v1 | public | t1
v2 | public | t1
v2 | public | t1
v2 | public | v1
v3 | public | t1
vm1 | public | mytest.tm1
mytest.vm1 | mytest | t1
vm2 | public | mytest.tm1
mytest.v2a | mytest | t1
mytest.v2a | mytest | t1
mytest.v2a | mytest | v1
(11 rows)
Listing View Definitions
This query lists the views that depend on t1
, the column referenced, and the view definition. The CREATE VIEW
command is created by adding the appropriate text to the view definition.
SELECT v.relname AS view,
d.refobjid::regclass as ref_object,
d.refobjsubid as ref_col,
'CREATE VIEW ' || v.relname || ' AS ' || pg_get_viewdef(v.oid) AS view_def
FROM pg_depend AS d
JOIN pg_rewrite AS r
ON r.oid = d.objid
JOIN pg_class AS v
ON v.oid = r.ev_class
WHERE NOT (v.oid = d.refobjid)
AND d.refobjid = 't1'::regclass
ORDER BY d.refobjsubid
;
view | ref_object | ref_col | view_def
------+------------+---------+--------------------------------------------
v1 | t1 | 1 | CREATE VIEW v1 AS SELECT max(t1.id) AS id+
| | | FROM t1;
v2a | t1 | 1 | CREATE VIEW v2a AS SELECT t1.val +
| | | FROM (t1 +
| | | JOIN v1 USING (id));
vt1 | t1 | 1 | CREATE VIEW vt1 AS SELECT t1.id +
| | | FROM t1 +
| | | WHERE (t1.id < 3);
v2 | t1 | 1 | CREATE VIEW v2 AS SELECT t1.val +
| | | FROM (t1 +
| | | JOIN v1 USING (id));
v2a | t1 | 2 | CREATE VIEW v2a AS SELECT t1.val +
| | | FROM (t1 +
| | | JOIN v1 USING (id));
v3 | t1 | 2 | CREATE VIEW v3 AS SELECT (t1.val || f()) +
| | | FROM t1;
v2 | t1 | 2 | CREATE VIEW v2 AS SELECT t1.val +
| | | FROM (t1 +
| | | JOIN v1 USING (id));
(7 rows)
Listing Nested Views
This CTE query lists information about views that reference another view.
The WITH
clause in this CTE query selects all the views in the user schemas. The main SELECT
statement finds all views that reference another view.
WITH views AS ( SELECT v.relname AS view,
d.refobjid AS ref_object,
v.oid AS view_oid,
ns.nspname AS namespace
FROM pg_depend AS d
JOIN pg_rewrite AS r
ON r.oid = d.objid
JOIN pg_class AS v
ON v.oid = r.ev_class
JOIN pg_namespace AS ns
ON ns.oid = v.relnamespace
WHERE v.relkind = 'v'
AND ns.nspname NOT IN ('pg_catalog', 'information_schema', 'gp_toolkit') -- exclude system schemas
AND d.deptype = 'n' -- normal dependency
AND NOT (v.oid = d.refobjid) -- not a self-referencing dependency
)
SELECT views.view, views.namespace AS schema,
views.ref_object::regclass AS ref_view,
ref_nspace.nspname AS ref_schema
FROM views
JOIN pg_depend as dep
ON dep.refobjid = views.view_oid
JOIN pg_class AS class
ON views.ref_object = class.oid
JOIN pg_namespace AS ref_nspace
ON class.relnamespace = ref_nspace.oid
WHERE class.relkind = 'v'
AND dep.deptype = 'n'
;
view | schema | ref_view | ref_schema
------+--------+----------+------------
v2 | public | v1 | public
v2a | mytest | v1 | public
Example Data
The output for the example queries is based on these database objects and data.
CREATE TABLE t1 (
id integer PRIMARY KEY,
val text NOT NULL
);
INSERT INTO t1 VALUES
(1, 'one'), (2, 'two'), (3, 'three');
CREATE FUNCTION f() RETURNS text
LANGUAGE sql AS 'SELECT ''suffix''::text';
CREATE VIEW v1 AS
SELECT max(id) AS id
FROM t1;
CREATE VIEW v2 AS
SELECT t1.val
FROM t1 JOIN v1 USING (id);
CREATE VIEW v3 AS
SELECT val || f()
FROM t1;
CREATE VIEW v5 AS
SELECT f() ;
CREATE SCHEMA mytest ;
CREATE TABLE mytest.tm1 (
id integer PRIMARY KEY,
val text NOT NULL
);
INSERT INTO mytest.tm1 VALUES
(1, 'one'), (2, 'two'), (3, 'three');
CREATE VIEW vm1 AS
SELECT id FROM mytest.tm1 WHERE id < 3 ;
CREATE VIEW mytest.vm1 AS
SELECT id FROM public.t1 WHERE id < 3 ;
CREATE VIEW vm2 AS
SELECT max(id) AS id
FROM mytest.tm1;
CREATE VIEW mytest.v2a AS
SELECT t1.val
FROM public.t1 JOIN public.v1 USING (id);