1 <?xml version="1.0" encoding="UTF-8" standalone="no"?>
2 <!DOCTYPE html PUBLIC "-//W3C//DTD XHTML 1.0 Transitional//EN" "http://www.w3.org/TR/xhtml1/DTD/xhtml1-transitional.dtd"><html xmlns="http://www.w3.org/1999/xhtml"><head><meta http-equiv="Content-Type" content="text/html; charset=UTF-8" /><title>5.15. Dependency Tracking</title><link rel="stylesheet" type="text/css" href="stylesheet.css" /><link rev="made" href="pgsql-docs@lists.postgresql.org" /><meta name="generator" content="DocBook XSL Stylesheets Vsnapshot" /><link rel="prev" href="ddl-others.html" title="5.14. Other Database Objects" /><link rel="next" href="dml.html" title="Chapter 6. Data Manipulation" /></head><body id="docContent" class="container-fluid col-10"><div class="navheader"><table width="100%" summary="Navigation header"><tr><th colspan="5" align="center">5.15. Dependency Tracking</th></tr><tr><td width="10%" align="left"><a accesskey="p" href="ddl-others.html" title="5.14. Other Database Objects">Prev</a> </td><td width="10%" align="left"><a accesskey="u" href="ddl.html" title="Chapter 5. Data Definition">Up</a></td><th width="60%" align="center">Chapter 5. Data Definition</th><td width="10%" align="right"><a accesskey="h" href="index.html" title="PostgreSQL 18.0 Documentation">Home</a></td><td width="10%" align="right"> <a accesskey="n" href="dml.html" title="Chapter 6. Data Manipulation">Next</a></td></tr></table><hr /></div><div class="sect1" id="DDL-DEPEND"><div class="titlepage"><div><div><h2 class="title" style="clear: both">5.15. Dependency Tracking <a href="#DDL-DEPEND" class="id_link">#</a></h2></div></div></div><a id="id-1.5.4.17.2" class="indexterm"></a><a id="id-1.5.4.17.3" class="indexterm"></a><p>
3 When you create complex database structures involving many tables
4 with foreign key constraints, views, triggers, functions, etc. you
5 implicitly create a net of dependencies between the objects.
6 For instance, a table with a foreign key constraint depends on the
9 To ensure the integrity of the entire database structure,
10 <span class="productname">PostgreSQL</span> makes sure that you cannot
11 drop objects that other objects still depend on. For example,
12 attempting to drop the products table we considered in <a class="xref" href="ddl-constraints.html#DDL-CONSTRAINTS-FK" title="5.5.5. Foreign Keys">Section 5.5.5</a>, with the orders table depending on
13 it, would result in an error message like this:
14 </p><pre class="screen">
17 ERROR: cannot drop table products because other objects depend on it
18 DETAIL: constraint orders_product_no_fkey on table orders depends on table products
19 HINT: Use DROP ... CASCADE to drop the dependent objects too.
21 The error message contains a useful hint: if you do not want to
22 bother deleting all the dependent objects individually, you can run:
23 </p><pre class="screen">
24 DROP TABLE products CASCADE;
26 and all the dependent objects will be removed, as will any objects
27 that depend on them, recursively. In this case, it doesn't remove
28 the orders table, it only removes the foreign key constraint.
29 It stops there because nothing depends on the foreign key constraint.
30 (If you want to check what <code class="command">DROP ... CASCADE</code> will do,
31 run <code class="command">DROP</code> without <code class="literal">CASCADE</code> and read the
32 <code class="literal">DETAIL</code> output.)
34 Almost all <code class="command">DROP</code> commands in <span class="productname">PostgreSQL</span> support
35 specifying <code class="literal">CASCADE</code>. Of course, the nature of
36 the possible dependencies varies with the type of the object. You
37 can also write <code class="literal">RESTRICT</code> instead of
38 <code class="literal">CASCADE</code> to get the default behavior, which is to
39 prevent dropping objects that any other objects depend on.
40 </p><div class="note"><h3 class="title">Note</h3><p>
41 According to the SQL standard, specifying either
42 <code class="literal">RESTRICT</code> or <code class="literal">CASCADE</code> is
43 required in a <code class="command">DROP</code> command. No database system actually
44 enforces that rule, but whether the default behavior
45 is <code class="literal">RESTRICT</code> or <code class="literal">CASCADE</code> varies
48 If a <code class="command">DROP</code> command lists multiple
49 objects, <code class="literal">CASCADE</code> is only required when there are
50 dependencies outside the specified group. For example, when saying
51 <code class="literal">DROP TABLE tab1, tab2</code> the existence of a foreign
52 key referencing <code class="literal">tab1</code> from <code class="literal">tab2</code> would not mean
53 that <code class="literal">CASCADE</code> is needed to succeed.
55 For a user-defined function or procedure whose body is defined as a string
56 literal, <span class="productname">PostgreSQL</span> tracks
57 dependencies associated with the function's externally-visible properties,
58 such as its argument and result types, but <span class="emphasis"><em>not</em></span> dependencies
59 that could only be known by examining the function body. As an example,
60 consider this situation:
62 </p><pre class="programlisting">
63 CREATE TYPE rainbow AS ENUM ('red', 'orange', 'yellow',
64 'green', 'blue', 'purple');
66 CREATE TABLE my_colors (color rainbow, note text);
68 CREATE FUNCTION get_color_note (rainbow) RETURNS text AS
69 'SELECT note FROM my_colors WHERE color = $1'
73 (See <a class="xref" href="xfunc-sql.html" title="36.5. Query Language (SQL) Functions">Section 36.5</a> for an explanation of SQL-language
74 functions.) <span class="productname">PostgreSQL</span> will be aware that
75 the <code class="function">get_color_note</code> function depends on the <code class="type">rainbow</code>
76 type: dropping the type would force dropping the function, because its
77 argument type would no longer be defined. But <span class="productname">PostgreSQL</span>
78 will not consider <code class="function">get_color_note</code> to depend on
79 the <code class="structname">my_colors</code> table, and so will not drop the function if
80 the table is dropped. While there are disadvantages to this approach,
81 there are also benefits. The function is still valid in some sense if the
82 table is missing, though executing it would cause an error; creating a new
83 table of the same name would allow the function to work again.
85 On the other hand, for an SQL-language function or procedure whose body
86 is written in SQL-standard style, the body is parsed at function
87 definition time and all dependencies recognized by the parser are
88 stored. Thus, if we write the function above as
90 </p><pre class="programlisting">
91 CREATE FUNCTION get_color_note (rainbow) RETURNS text
93 SELECT note FROM my_colors WHERE color = $1;
97 then the function's dependency on the <code class="structname">my_colors</code>
98 table will be known and enforced by <code class="command">DROP</code>.
99 </p></div><div class="navfooter"><hr /><table width="100%" summary="Navigation footer"><tr><td width="40%" align="left"><a accesskey="p" href="ddl-others.html" title="5.14. Other Database Objects">Prev</a> </td><td width="20%" align="center"><a accesskey="u" href="ddl.html" title="Chapter 5. Data Definition">Up</a></td><td width="40%" align="right"> <a accesskey="n" href="dml.html" title="Chapter 6. Data Manipulation">Next</a></td></tr><tr><td width="40%" align="left" valign="top">5.14. Other Database Objects </td><td width="20%" align="center"><a accesskey="h" href="index.html" title="PostgreSQL 18.0 Documentation">Home</a></td><td width="40%" align="right" valign="top"> Chapter 6. Data Manipulation</td></tr></table></div></body></html>