1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 70 71 72 73 74 75 76 77 78 79 80 81 82 83 84 85 86 87 88 89 90 91 92 93 94 95 96 97 98 99 100 101 102 103 104 105 106 107 108 109 110 111 112 113 114 115 116 117 118 119 120 121 122 123 124 125 126 127 128 129 130 131 132 133 134 135 136 137 138 139 140 141 142 143 144 145 146 147 148 149 150 151 152 153 154 155 156 157 158 159 160 161 162 163 164 165 166 167 168 169 170 171 172 173 174 175 176 177 178 179 180 181 182 183 184 185 186 187 188 189 190 191 192 193 194 195 196 197 198 199 200 201 202 203 204 205 206 207 208 209 210 211 212 213 214 215 216 217 218 219 220 221 222 223 224 225 226 227 228 229 230 231 232 233 234 235 236 237 238 239 240 241 242 243 244 245 246 247 248 249 250 251 252 253 254 255 256 257 258 259 260 261 262 263 264 265 266 267 268 269 270 271 272 273 274 275 276 277 278 279 280 281 282 283 284 285 286 287 288 289 290 291 292 293 294 295 296 297 298 299 300 301 302 303 304 305 306 307 308 309 310 311 312 313 314 315 316 317 318 319 320 321 322 323 324 325 326 327 328 329 330 331 332 333 334 335 336 337 338 339 340 341 342 343 344
|
<html>
<head>
<meta http-equiv="Content-Type" content="text/html; charset=ISO-8859-1">
<title>5.7.Schemas</title>
<link rel="stylesheet" href="stylesheet.css" type="text/css">
<link rev="made" href="pgsql-docs@postgresql.org">
<meta name="generator" content="DocBook XSL Stylesheets V1.70.0">
<link rel="start" href="index.html" title="PostgreSQL 8.1.4 Documentation">
<link rel="up" href="ddl.html" title="Chapter5.Data Definition">
<link rel="prev" href="ddl-priv.html" title="5.6.Privileges">
<link rel="next" href="ddl-inherit.html" title="5.8.Inheritance">
<link rel="copyright" href="ln-legalnotice.html" title="Legal Notice">
</head>
<body bgcolor="white" text="black" link="#0000FF" vlink="#840084" alink="#0000FF"><div class="sect1" lang="en">
<div class="titlepage"><div><div><h2 class="title" style="clear: both">
<a name="ddl-schemas"></a>5.7.Schemas</h2></div></div></div>
<a name="id576847"></a><p> A <span class="productname">PostgreSQL</span> database cluster
contains one or more named databases. Users and groups of users are
shared across the entire cluster, but no other data is shared across
databases. Any given client connection to the server can access
only the data in a single database, the one specified in the connection
request.
</p>
<div class="note" style="margin-left: 0.5in; margin-right: 0.5in;">
<h3 class="title">Note</h3>
<p> Users of a cluster do not necessarily have the privilege to access every
database in the cluster. Sharing of user names means that there
cannot be different users named, say, <code class="literal">joe</code> in two databases
in the same cluster; but the system can be configured to allow
<code class="literal">joe</code> access to only some of the databases.
</p>
</div>
<p> A database contains one or more named <em class="firstterm">schemas</em>, which
in turn contain tables. Schemas also contain other kinds of named
objects, including data types, functions, and operators. The same
object name can be used in different schemas without conflict; for
example, both <code class="literal">schema1</code> and <code class="literal">myschema</code> may
contain tables named <code class="literal">mytable</code>. Unlike databases,
schemas are not rigidly separated: a user may access objects in any
of the schemas in the database he is connected to, if he has
privileges to do so.
</p>
<p> There are several reasons why one might want to use schemas:
</p>
<div class="itemizedlist"><ul type="disc">
<li><p> To allow many users to use one database without interfering with
each other.
</p></li>
<li><p> To organize database objects into logical groups to make them
more manageable.
</p></li>
<li><p> Third-party applications can be put into separate schemas so
they cannot collide with the names of other objects.
</p></li>
</ul></div>
<p>
Schemas are analogous to directories at the operating system level,
except that schemas cannot be nested.
</p>
<div class="sect2" lang="en">
<div class="titlepage"><div><div><h3 class="title">
<a name="ddl-schemas-create"></a>5.7.1.Creating a Schema</h3></div></div></div>
<a name="id576956"></a><p> To create a schema, use the command <code class="command">CREATE
SCHEMA</code>. Give the schema a name of your choice. For
example:
</p>
<pre class="programlisting">CREATE SCHEMA myschema;</pre>
<p>
</p>
<a name="id576988"></a><a name="id576994"></a><p> To create or access objects in a schema, write a
<em class="firstterm">qualified name</em> consisting of the schema name and
table name separated by a dot:
</p>
<pre class="synopsis"><em class="replaceable"><code>schema</code></em><code class="literal">.</code><em class="replaceable"><code>table</code></em></pre>
<p>
This works anywhere a table name is expected, including the table
modification commands and the data access commands discussed in
the following chapters.
(For brevity we will speak of tables only, but the same ideas apply
to other kinds of named objects, such as types and functions.)
</p>
<p> Actually, the even more general syntax
</p>
<pre class="synopsis"><em class="replaceable"><code>database</code></em><code class="literal">.</code><em class="replaceable"><code>schema</code></em><code class="literal">.</code><em class="replaceable"><code>table</code></em></pre>
<p>
can be used too, but at present this is just for <span class="foreignphrase"><em class="foreignphrase">pro
forma</em></span> compliance with the SQL standard. If you write a database name,
it must be the same as the database you are connected to.
</p>
<p> So to create a table in the new schema, use
</p>
<pre class="programlisting">CREATE TABLE myschema.mytable (
...
);</pre>
<p>
</p>
<a name="id577077"></a><p> To drop a schema if it's empty (all objects in it have been
dropped), use
</p>
<pre class="programlisting">DROP SCHEMA myschema;</pre>
<p>
To drop a schema including all contained objects, use
</p>
<pre class="programlisting">DROP SCHEMA myschema CASCADE;</pre>
<p>
See <a href="ddl-depend.html" title="5.11.Dependency Tracking">Section5.11, “Dependency Tracking”</a> for a description of the general
mechanism behind this.
</p>
<p> Often you will want to create a schema owned by someone else
(since this is one of the ways to restrict the activities of your
users to well-defined namespaces). The syntax for that is:
</p>
<pre class="programlisting">CREATE SCHEMA <em class="replaceable"><code>schemaname</code></em> AUTHORIZATION <em class="replaceable"><code>username</code></em>;</pre>
<p>
You can even omit the schema name, in which case the schema name
will be the same as the user name. See <a href="ddl-schemas.html#ddl-schemas-patterns" title="5.7.6.Usage Patterns">Section5.7.6, “Usage Patterns”</a> for how this can be useful.
</p>
<p> Schema names beginning with <code class="literal">pg_</code> are reserved for
system purposes and may not be created by users.
</p>
</div>
<div class="sect2" lang="en">
<div class="titlepage"><div><div><h3 class="title">
<a name="ddl-schemas-public"></a>5.7.2.The Public Schema</h3></div></div></div>
<a name="id577163"></a><p> In the previous sections we created tables without specifying any
schema names. By default, such tables (and other objects) are
automatically put into a schema named “<span class="quote">public</span>”. Every new
database contains such a schema. Thus, the following are equivalent:
</p>
<pre class="programlisting">CREATE TABLE products ( ... );</pre>
<p>
and
</p>
<pre class="programlisting">CREATE TABLE public.products ( ... );</pre>
<p>
</p>
</div>
<div class="sect2" lang="en">
<div class="titlepage"><div><div><h3 class="title">
<a name="ddl-schemas-path"></a>5.7.3.The Schema Search Path</h3></div></div></div>
<a name="id577211"></a><a name="id577217"></a><a name="id577224"></a><p> Qualified names are tedious to write, and it's often best not to
wire a particular schema name into applications anyway. Therefore
tables are often referred to by <em class="firstterm">unqualified names</em>,
which consist of just the table name. The system determines which table
is meant by following a <em class="firstterm">search path</em>, which is a list
of schemas to look in. The first matching table in the search path
is taken to be the one wanted. If there is no match in the search
path, an error is reported, even if matching table names exist
in other schemas in the database.
</p>
<a name="id577253"></a><p> The first schema named in the search path is called the current schema.
Aside from being the first schema searched, it is also the schema in
which new tables will be created if the <code class="command">CREATE TABLE</code>
command does not specify a schema name.
</p>
<a name="id577275"></a><p> To show the current search path, use the following command:
</p>
<pre class="programlisting">SHOW search_path;</pre>
<p>
In the default setup this returns:
</p>
<pre class="screen"> search_path
--------------
$user,public</pre>
<p>
The first element specifies that a schema with the same name as
the current user is to be searched. If no such schema exists,
the entry is ignored. The second element refers to the
public schema that we have seen already.
</p>
<p> The first schema in the search path that exists is the default
location for creating new objects. That is the reason that by
default objects are created in the public schema. When objects
are referenced in any other context without schema qualification
(table modification, data modification, or query commands) the
search path is traversed until a matching object is found.
Therefore, in the default configuration, any unqualified access
again can only refer to the public schema.
</p>
<p> To put our new schema in the path, we use
</p>
<pre class="programlisting">SET search_path TO myschema,public;</pre>
<p>
(We omit the <code class="literal">$user</code> here because we have no
immediate need for it.) And then we can access the table without
schema qualification:
</p>
<pre class="programlisting">DROP TABLE mytable;</pre>
<p>
Also, since <code class="literal">myschema</code> is the first element in
the path, new objects would by default be created in it.
</p>
<p> We could also have written
</p>
<pre class="programlisting">SET search_path TO myschema;</pre>
<p>
Then we no longer have access to the public schema without
explicit qualification. There is nothing special about the public
schema except that it exists by default. It can be dropped, too.
</p>
<p> See also <a href="functions-info.html" title="9.19.System Information Functions">Section9.19, “System Information Functions”</a> for other ways to manipulate
the schema search path.
</p>
<p> The search path works in the same way for data type names, function names,
and operator names as it does for table names. Data type and function
names can be qualified in exactly the same way as table names. If you
need to write a qualified operator name in an expression, there is a
special provision: you must write
</p>
<pre class="synopsis"><code class="literal">OPERATOR(</code><em class="replaceable"><code>schema</code></em><code class="literal">.</code><em class="replaceable"><code>operator</code></em><code class="literal">)</code></pre>
<p>
This is needed to avoid syntactic ambiguity. An example is
</p>
<pre class="programlisting">SELECT 3 OPERATOR(pg_catalog.+) 4;</pre>
<p>
In practice one usually relies on the search path for operators,
so as not to have to write anything so ugly as that.
</p>
</div>
<div class="sect2" lang="en">
<div class="titlepage"><div><div><h3 class="title">
<a name="ddl-schemas-priv"></a>5.7.4.Schemas and Privileges</h3></div></div></div>
<a name="id577419"></a><p> By default, users cannot access any objects in schemas they do not
own. To allow that, the owner of the schema needs to grant the
<code class="literal">USAGE</code> privilege on the schema. To allow users
to make use of the objects in the schema, additional privileges
may need to be granted, as appropriate for the object.
</p>
<p> A user can also be allowed to create objects in someone else's
schema. To allow that, the <code class="literal">CREATE</code> privilege on
the schema needs to be granted. Note that by default, everyone
has <code class="literal">CREATE</code> and <code class="literal">USAGE</code> privileges on
the schema
<code class="literal">public</code>. This allows all users that are able to
connect to a given database to create objects in its
<code class="literal">public</code> schema. If you do
not want to allow that, you can revoke that privilege:
</p>
<pre class="programlisting">REVOKE CREATE ON SCHEMA public FROM PUBLIC;</pre>
<p>
(The first “<span class="quote">public</span>” is the schema, the second
“<span class="quote">public</span>” means “<span class="quote">every user</span>”. In the
first sense it is an identifier, in the second sense it is a
key word, hence the different capitalization; recall the
guidelines from <a href="sql-syntax.html#sql-syntax-identifiers" title="4.1.1.Identifiers and Key Words">Section4.1.1, “Identifiers and Key Words”</a>.)
</p>
</div>
<div class="sect2" lang="en">
<div class="titlepage"><div><div><h3 class="title">
<a name="ddl-schemas-catalog"></a>5.7.5.The System Catalog Schema</h3></div></div></div>
<a name="id577530"></a><p> In addition to <code class="literal">public</code> and user-created schemas, each
database contains a <code class="literal">pg_catalog</code> schema, which contains
the system tables and all the built-in data types, functions, and
operators. <code class="literal">pg_catalog</code> is always effectively part of
the search path. If it is not named explicitly in the path then
it is implicitly searched <span class="emphasis"><em>before</em></span> searching the path's
schemas. This ensures that built-in names will always be
findable. However, you may explicitly place
<code class="literal">pg_catalog</code> at the end of your search path if you
prefer to have user-defined names override built-in names.
</p>
<p> In <span class="productname">PostgreSQL</span> versions before 7.3,
table names beginning with <code class="literal">pg_</code> were reserved. This is
no longer true: you may create such a table name if you wish, in
any non-system schema. However, it's best to continue to avoid
such names, to ensure that you won't suffer a conflict if some
future version defines a system table named the same as your
table. (With the default search path, an unqualified reference to
your table name would be resolved as the system table instead.)
System tables will continue to follow the convention of having
names beginning with <code class="literal">pg_</code>, so that they will not
conflict with unqualified user-table names so long as users avoid
the <code class="literal">pg_</code> prefix.
</p>
</div>
<div class="sect2" lang="en">
<div class="titlepage"><div><div><h3 class="title">
<a name="ddl-schemas-patterns"></a>5.7.6.Usage Patterns</h3></div></div></div>
<p> Schemas can be used to organize your data in many ways. There are
a few usage patterns that are recommended and are easily supported by
the default configuration:
</p>
<div class="itemizedlist"><ul type="disc">
<li><p> If you do not create any schemas then all users access the
public schema implicitly. This simulates the situation where
schemas are not available at all. This setup is mainly
recommended when there is only a single user or a few cooperating
users in a database. This setup also allows smooth transition
from the non-schema-aware world.
</p></li>
<li>
<p> You can create a schema for each user with the same name as
that user. Recall that the default search path starts with
<code class="literal">$user</code>, which resolves to the user name.
Therefore, if each user has a separate schema, they access their
own schemas by default.
</p>
<p> If you use this setup then you might also want to revoke access
to the public schema (or drop it altogether), so users are
truly constrained to their own schemas.
</p>
</li>
<li><p> To install shared applications (tables to be used by everyone,
additional functions provided by third parties, etc.), put them
into separate schemas. Remember to grant appropriate
privileges to allow the other users to access them. Users can
then refer to these additional objects by qualifying the names
with a schema name, or they can put the additional schemas into
their search path, as they choose.
</p></li>
</ul></div>
<p>
</p>
</div>
<div class="sect2" lang="en">
<div class="titlepage"><div><div><h3 class="title">
<a name="ddl-schemas-portability"></a>5.7.7.Portability</h3></div></div></div>
<p> In the SQL standard, the notion of objects in the same schema
being owned by different users does not exist. Moreover, some
implementations do not allow you to create schemas that have a
different name than their owner. In fact, the concepts of schema
and user are nearly equivalent in a database system that
implements only the basic schema support specified in the
standard. Therefore, many users consider qualified names to
really consist of
<code class="literal"><em class="replaceable"><code>username</code></em>.<em class="replaceable"><code>tablename</code></em></code>.
This is how <span class="productname">PostgreSQL</span> will effectively
behave if you create a per-user schema for every user.
</p>
<p> Also, there is no concept of a <code class="literal">public</code> schema in the
SQL standard. For maximum conformance to the standard, you should
not use (perhaps even remove) the <code class="literal">public</code> schema.
</p>
<p> Of course, some SQL database systems might not implement schemas
at all, or provide namespace support by allowing (possibly
limited) cross-database access. If you need to work with those
systems, then maximum portability would be achieved by not using
schemas at all.
</p>
</div>
</div></body>
</html>
|