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.

  1. CREATE TABLE t (id integer PRIMARY KEY);
  2. CREATE VIEW v AS SELECT * FROM t;
  3. DROP TABLE t;
  4. ERROR: cannot drop table t because other objects depend on it
  5. DETAIL: view v depends on table t
  6. HINT: Use DROP ... CASCADE to drop the dependent objects too.
  7. ALTER TABLE t DROP id;
  8. ERROR: cannot drop column id of table t because other objects depend on it
  9. DETAIL: view v depends on column id of table t
  10. 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.

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.

  1. SELECT v.oid::regclass AS view,
  2. d.refobjid::regclass AS ref_object -- name of table
  3. -- d.refobjid::regproc AS ref_object -- name of function
  4. FROM pg_depend AS d -- objects that depend on a table
  5. JOIN pg_rewrite AS r -- rules depending on a table
  6. ON r.oid = d.objid
  7. JOIN pg_class AS v -- views for the rules
  8. ON v.oid = r.ev_class
  9. WHERE v.relkind = 'v' -- filter views only
  10. -- dependency must be a rule depending on a relation
  11. AND d.classid = 'pg_rewrite'::regclass
  12. AND d.deptype = 'n' -- normal dependency
  13. -- qualify object
  14. AND d.refclassid = 'pg_class'::regclass -- dependent table
  15. AND d.refobjid = 't1'::regclass
  16. -- AND d.refclassid = 'pg_proc'::regclass -- dependent function
  17. -- AND d.refobjid = 'f'::regproc
  18. ;
  19. view | ref_object
  20. ------------+------------
  21. v1 | t1
  22. v2 | t1
  23. v2 | t1
  24. v3 | t1
  25. mytest.vt1 | t1
  26. mytest.v2a | t1
  27. mytest.v2a | t1
  28. (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 table d.refobjid::regclass as ref_object with the name of the function d.refobjid::regproc as ref_object
  • In the WHERE clause replace the catalog of the referenced object from d.refclassid = 'pg_class'::regclass for tables, to d.refclassid = 'pg_proc'::regclass for procedures (functions). Also change the object name from d.refobjid = 't1'::regclass to d.refobjid = 'f'::regproc
  • In the WHERE clause, replace the name of the table refobjid = 't1'::regclass with the name of the function refobjid = '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:

  1. SELECT v.oid::regclass AS view,
  2. d.refobjid::regclass AS ref_object, -- name of table
  3. a.attname AS col_name -- column name
  4. FROM pg_attribute AS a -- columns for a table
  5. JOIN pg_depend AS d -- objects that depend on a column
  6. ON d.refobjsubid = a.attnum AND d.refobjid = a.attrelid
  7. JOIN pg_rewrite AS r -- rules depending on the column
  8. ON r.oid = d.objid
  9. JOIN pg_class AS v -- views for the rules
  10. ON v.oid = r.ev_class
  11. WHERE v.relkind = 'v' -- filter views only
  12. -- dependency must be a rule depending on a relation
  13. AND d.classid = 'pg_rewrite'::regclass
  14. AND d.refclassid = 'pg_class'::regclass
  15. AND d.deptype = 'n' -- normal dependency
  16. AND a.attrelid = 't1'::regclass
  17. AND a.attname = 'id'
  18. ;
  19. view | ref_object | col_name
  20. ------------+------------+----------
  21. v1 | t1 | id
  22. v2 | t1 | id
  23. mytest.vt1 | t1 | id
  24. mytest.v2a | t1 | id
  25. (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.

  1. SELECT v.oid::regclass AS view,
  2. ns.nspname AS schema, -- view schema,
  3. d.refobjid::regclass AS ref_object -- name of table
  4. FROM pg_depend AS d -- objects that depend on a table
  5. JOIN pg_rewrite AS r -- rules depending on a table
  6. ON r.oid = d.objid
  7. JOIN pg_class AS v -- views for the rules
  8. ON v.oid = r.ev_class
  9. JOIN pg_namespace AS ns -- schema information
  10. ON ns.oid = v.relnamespace
  11. WHERE v.relkind = 'v' -- filter views only
  12. -- dependency must be a rule depending on a relation
  13. AND d.classid = 'pg_rewrite'::regclass
  14. AND d.refclassid = 'pg_class'::regclass -- referenced objects in pg_class -- tables and views
  15. AND d.deptype = 'n' -- normal dependency
  16. -- qualify object
  17. AND ns.nspname NOT IN ('pg_catalog', 'information_schema', 'gp_toolkit') -- system schemas
  18. AND NOT (v.oid = d.refobjid) -- not self-referencing dependency
  19. ;
  20. view | schema | ref_object
  21. ------------+--------+------------
  22. v1 | public | t1
  23. v2 | public | t1
  24. v2 | public | t1
  25. v2 | public | v1
  26. v3 | public | t1
  27. vm1 | public | mytest.tm1
  28. mytest.vm1 | mytest | t1
  29. vm2 | public | mytest.tm1
  30. mytest.v2a | mytest | t1
  31. mytest.v2a | mytest | t1
  32. mytest.v2a | mytest | v1
  33. (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.

  1. SELECT v.relname AS view,
  2. d.refobjid::regclass as ref_object,
  3. d.refobjsubid as ref_col,
  4. 'CREATE VIEW ' || v.relname || ' AS ' || pg_get_viewdef(v.oid) AS view_def
  5. FROM pg_depend AS d
  6. JOIN pg_rewrite AS r
  7. ON r.oid = d.objid
  8. JOIN pg_class AS v
  9. ON v.oid = r.ev_class
  10. WHERE NOT (v.oid = d.refobjid)
  11. AND d.refobjid = 't1'::regclass
  12. ORDER BY d.refobjsubid
  13. ;
  14. view | ref_object | ref_col | view_def
  15. ------+------------+---------+--------------------------------------------
  16. v1 | t1 | 1 | CREATE VIEW v1 AS SELECT max(t1.id) AS id+
  17. | | | FROM t1;
  18. v2a | t1 | 1 | CREATE VIEW v2a AS SELECT t1.val +
  19. | | | FROM (t1 +
  20. | | | JOIN v1 USING (id));
  21. vt1 | t1 | 1 | CREATE VIEW vt1 AS SELECT t1.id +
  22. | | | FROM t1 +
  23. | | | WHERE (t1.id < 3);
  24. v2 | t1 | 1 | CREATE VIEW v2 AS SELECT t1.val +
  25. | | | FROM (t1 +
  26. | | | JOIN v1 USING (id));
  27. v2a | t1 | 2 | CREATE VIEW v2a AS SELECT t1.val +
  28. | | | FROM (t1 +
  29. | | | JOIN v1 USING (id));
  30. v3 | t1 | 2 | CREATE VIEW v3 AS SELECT (t1.val || f()) +
  31. | | | FROM t1;
  32. v2 | t1 | 2 | CREATE VIEW v2 AS SELECT t1.val +
  33. | | | FROM (t1 +
  34. | | | JOIN v1 USING (id));
  35. (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.

  1. WITH views AS ( SELECT v.relname AS view,
  2. d.refobjid AS ref_object,
  3. v.oid AS view_oid,
  4. ns.nspname AS namespace
  5. FROM pg_depend AS d
  6. JOIN pg_rewrite AS r
  7. ON r.oid = d.objid
  8. JOIN pg_class AS v
  9. ON v.oid = r.ev_class
  10. JOIN pg_namespace AS ns
  11. ON ns.oid = v.relnamespace
  12. WHERE v.relkind = 'v'
  13. AND ns.nspname NOT IN ('pg_catalog', 'information_schema', 'gp_toolkit') -- exclude system schemas
  14. AND d.deptype = 'n' -- normal dependency
  15. AND NOT (v.oid = d.refobjid) -- not a self-referencing dependency
  16. )
  17. SELECT views.view, views.namespace AS schema,
  18. views.ref_object::regclass AS ref_view,
  19. ref_nspace.nspname AS ref_schema
  20. FROM views
  21. JOIN pg_depend as dep
  22. ON dep.refobjid = views.view_oid
  23. JOIN pg_class AS class
  24. ON views.ref_object = class.oid
  25. JOIN pg_namespace AS ref_nspace
  26. ON class.relnamespace = ref_nspace.oid
  27. WHERE class.relkind = 'v'
  28. AND dep.deptype = 'n'
  29. ;
  30. view | schema | ref_view | ref_schema
  31. ------+--------+----------+------------
  32. v2 | public | v1 | public
  33. v2a | mytest | v1 | public

Example Data

The output for the example queries is based on these database objects and data.

  1. CREATE TABLE t1 (
  2. id integer PRIMARY KEY,
  3. val text NOT NULL
  4. );
  5. INSERT INTO t1 VALUES
  6. (1, 'one'), (2, 'two'), (3, 'three');
  7. CREATE FUNCTION f() RETURNS text
  8. LANGUAGE sql AS 'SELECT ''suffix''::text';
  9. CREATE VIEW v1 AS
  10. SELECT max(id) AS id
  11. FROM t1;
  12. CREATE VIEW v2 AS
  13. SELECT t1.val
  14. FROM t1 JOIN v1 USING (id);
  15. CREATE VIEW v3 AS
  16. SELECT val || f()
  17. FROM t1;
  18. CREATE VIEW v5 AS
  19. SELECT f() ;
  20. CREATE SCHEMA mytest ;
  21. CREATE TABLE mytest.tm1 (
  22. id integer PRIMARY KEY,
  23. val text NOT NULL
  24. );
  25. INSERT INTO mytest.tm1 VALUES
  26. (1, 'one'), (2, 'two'), (3, 'three');
  27. CREATE VIEW vm1 AS
  28. SELECT id FROM mytest.tm1 WHERE id < 3 ;
  29. CREATE VIEW mytest.vm1 AS
  30. SELECT id FROM public.t1 WHERE id < 3 ;
  31. CREATE VIEW vm2 AS
  32. SELECT max(id) AS id
  33. FROM mytest.tm1;
  34. CREATE VIEW mytest.v2a AS
  35. SELECT t1.val
  36. FROM public.t1 JOIN public.v1 USING (id);