gooderp18绿色标准版
您最多选择25个主题 主题必须以字母或数字开头,可以包含连字符 (-),并且长度不得超过35个字符

320 行
22KB

  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.9. Schemas</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 V1.79.1" /><link rel="prev" href="ddl-rowsecurity.html" title="5.8. Row Security Policies" /><link rel="next" href="ddl-inherit.html" title="5.10. Inheritance" /></head><body><div xmlns="http://www.w3.org/TR/xhtml1/transitional" class="navheader"><table width="100%" summary="Navigation header"><tr><th colspan="5" align="center">5.9. Schemas</th></tr><tr><td width="10%" align="left"><a accesskey="p" href="ddl-rowsecurity.html" title="5.8. Row Security Policies">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 12.4 Documentation">Home</a></td><td width="10%" align="right"> <a accesskey="n" href="ddl-inherit.html" title="5.10. Inheritance">Next</a></td></tr></table><hr></hr></div><div class="sect1" id="DDL-SCHEMAS"><div class="titlepage"><div><div><h2 class="title" style="clear: both">5.9. Schemas</h2></div></div></div><div class="toc"><dl class="toc"><dt><span class="sect2"><a href="ddl-schemas.html#DDL-SCHEMAS-CREATE">5.9.1. Creating a Schema</a></span></dt><dt><span class="sect2"><a href="ddl-schemas.html#DDL-SCHEMAS-PUBLIC">5.9.2. The Public Schema</a></span></dt><dt><span class="sect2"><a href="ddl-schemas.html#DDL-SCHEMAS-PATH">5.9.3. The Schema Search Path</a></span></dt><dt><span class="sect2"><a href="ddl-schemas.html#DDL-SCHEMAS-PRIV">5.9.4. Schemas and Privileges</a></span></dt><dt><span class="sect2"><a href="ddl-schemas.html#DDL-SCHEMAS-CATALOG">5.9.5. The System Catalog Schema</a></span></dt><dt><span class="sect2"><a href="ddl-schemas.html#DDL-SCHEMAS-PATTERNS">5.9.6. Usage Patterns</a></span></dt><dt><span class="sect2"><a href="ddl-schemas.html#DDL-SCHEMAS-PORTABILITY">5.9.7. Portability</a></span></dt></dl></div><a id="id-1.5.4.11.2" class="indexterm"></a><p>
  3. A <span class="productname">PostgreSQL</span> database cluster contains
  4. one or more named databases. Roles and a few other object types are
  5. shared across the entire cluster. A client connection to the server
  6. can only access data in a single database, the one specified in the
  7. connection request.
  8. </p><div class="note"><h3 class="title">Note</h3><p>
  9. Users of a cluster do not necessarily have the privilege to access every
  10. database in the cluster. Sharing of role names means that there
  11. cannot be different roles named, say, <code class="literal">joe</code> in two databases
  12. in the same cluster; but the system can be configured to allow
  13. <code class="literal">joe</code> access to only some of the databases.
  14. </p></div><p>
  15. A database contains one or more named <em class="firstterm">schemas</em>, which
  16. in turn contain tables. Schemas also contain other kinds of named
  17. objects, including data types, functions, and operators. The same
  18. object name can be used in different schemas without conflict; for
  19. example, both <code class="literal">schema1</code> and <code class="literal">myschema</code> can
  20. contain tables named <code class="literal">mytable</code>. Unlike databases,
  21. schemas are not rigidly separated: a user can access objects in any
  22. of the schemas in the database they are connected to, if they have
  23. privileges to do so.
  24. </p><p>
  25. There are several reasons why one might want to use schemas:
  26. </p><div class="itemizedlist"><ul class="itemizedlist" style="list-style-type: disc; "><li class="listitem"><p>
  27. To allow many users to use one database without interfering with
  28. each other.
  29. </p></li><li class="listitem"><p>
  30. To organize database objects into logical groups to make them
  31. more manageable.
  32. </p></li><li class="listitem"><p>
  33. Third-party applications can be put into separate schemas so
  34. they do not collide with the names of other objects.
  35. </p></li></ul></div><p>
  36. Schemas are analogous to directories at the operating system level,
  37. except that schemas cannot be nested.
  38. </p><div class="sect2" id="DDL-SCHEMAS-CREATE"><div class="titlepage"><div><div><h3 class="title">5.9.1. Creating a Schema</h3></div></div></div><a id="id-1.5.4.11.7.2" class="indexterm"></a><p>
  39. To create a schema, use the <a class="xref" href="sql-createschema.html" title="CREATE SCHEMA"><span class="refentrytitle">CREATE SCHEMA</span></a>
  40. command. Give the schema a name
  41. of your choice. For example:
  42. </p><pre class="programlisting">
  43. CREATE SCHEMA myschema;
  44. </pre><p>
  45. </p><a id="id-1.5.4.11.7.4" class="indexterm"></a><a id="id-1.5.4.11.7.5" class="indexterm"></a><p>
  46. To create or access objects in a schema, write a
  47. <em class="firstterm">qualified name</em> consisting of the schema name and
  48. table name separated by a dot:
  49. </p><pre class="synopsis">
  50. <em class="replaceable"><code>schema</code></em><code class="literal">.</code><em class="replaceable"><code>table</code></em>
  51. </pre><p>
  52. This works anywhere a table name is expected, including the table
  53. modification commands and the data access commands discussed in
  54. the following chapters.
  55. (For brevity we will speak of tables only, but the same ideas apply
  56. to other kinds of named objects, such as types and functions.)
  57. </p><p>
  58. Actually, the even more general syntax
  59. </p><pre class="synopsis">
  60. <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>
  61. </pre><p>
  62. can be used too, but at present this is just for <span class="foreignphrase"><em class="foreignphrase">pro
  63. forma</em></span> compliance with the SQL standard. If you write a database name,
  64. it must be the same as the database you are connected to.
  65. </p><p>
  66. So to create a table in the new schema, use:
  67. </p><pre class="programlisting">
  68. CREATE TABLE myschema.mytable (
  69. ...
  70. );
  71. </pre><p>
  72. </p><a id="id-1.5.4.11.7.9" class="indexterm"></a><p>
  73. To drop a schema if it's empty (all objects in it have been
  74. dropped), use:
  75. </p><pre class="programlisting">
  76. DROP SCHEMA myschema;
  77. </pre><p>
  78. To drop a schema including all contained objects, use:
  79. </p><pre class="programlisting">
  80. DROP SCHEMA myschema CASCADE;
  81. </pre><p>
  82. See <a class="xref" href="ddl-depend.html" title="5.14. Dependency Tracking">Section 5.14</a> for a description of the general
  83. mechanism behind this.
  84. </p><p>
  85. Often you will want to create a schema owned by someone else
  86. (since this is one of the ways to restrict the activities of your
  87. users to well-defined namespaces). The syntax for that is:
  88. </p><pre class="programlisting">
  89. CREATE SCHEMA <em class="replaceable"><code>schema_name</code></em> AUTHORIZATION <em class="replaceable"><code>user_name</code></em>;
  90. </pre><p>
  91. You can even omit the schema name, in which case the schema name
  92. will be the same as the user name. See <a class="xref" href="ddl-schemas.html#DDL-SCHEMAS-PATTERNS" title="5.9.6. Usage Patterns">Section 5.9.6</a> for how this can be useful.
  93. </p><p>
  94. Schema names beginning with <code class="literal">pg_</code> are reserved for
  95. system purposes and cannot be created by users.
  96. </p></div><div class="sect2" id="DDL-SCHEMAS-PUBLIC"><div class="titlepage"><div><div><h3 class="title">5.9.2. The Public Schema</h3></div></div></div><a id="id-1.5.4.11.8.2" class="indexterm"></a><p>
  97. In the previous sections we created tables without specifying any
  98. schema names. By default such tables (and other objects) are
  99. automatically put into a schema named <span class="quote">“<span class="quote">public</span>”</span>. Every new
  100. database contains such a schema. Thus, the following are equivalent:
  101. </p><pre class="programlisting">
  102. CREATE TABLE products ( ... );
  103. </pre><p>
  104. and:
  105. </p><pre class="programlisting">
  106. CREATE TABLE public.products ( ... );
  107. </pre><p>
  108. </p></div><div class="sect2" id="DDL-SCHEMAS-PATH"><div class="titlepage"><div><div><h3 class="title">5.9.3. The Schema Search Path</h3></div></div></div><a id="id-1.5.4.11.9.2" class="indexterm"></a><a id="id-1.5.4.11.9.3" class="indexterm"></a><a id="id-1.5.4.11.9.4" class="indexterm"></a><p>
  109. Qualified names are tedious to write, and it's often best not to
  110. wire a particular schema name into applications anyway. Therefore
  111. tables are often referred to by <em class="firstterm">unqualified names</em>,
  112. which consist of just the table name. The system determines which table
  113. is meant by following a <em class="firstterm">search path</em>, which is a list
  114. of schemas to look in. The first matching table in the search path
  115. is taken to be the one wanted. If there is no match in the search
  116. path, an error is reported, even if matching table names exist
  117. in other schemas in the database.
  118. </p><p>
  119. The ability to create like-named objects in different schemas complicates
  120. writing a query that references precisely the same objects every time. It
  121. also opens up the potential for users to change the behavior of other
  122. users' queries, maliciously or accidentally. Due to the prevalence of
  123. unqualified names in queries and their use
  124. in <span class="productname">PostgreSQL</span> internals, adding a schema
  125. to <code class="varname">search_path</code> effectively trusts all users having
  126. <code class="literal">CREATE</code> privilege on that schema. When you run an
  127. ordinary query, a malicious user able to create objects in a schema of
  128. your search path can take control and execute arbitrary SQL functions as
  129. though you executed them.
  130. </p><a id="id-1.5.4.11.9.7" class="indexterm"></a><p>
  131. The first schema named in the search path is called the current schema.
  132. Aside from being the first schema searched, it is also the schema in
  133. which new tables will be created if the <code class="command">CREATE TABLE</code>
  134. command does not specify a schema name.
  135. </p><a id="id-1.5.4.11.9.9" class="indexterm"></a><p>
  136. To show the current search path, use the following command:
  137. </p><pre class="programlisting">
  138. SHOW search_path;
  139. </pre><p>
  140. In the default setup this returns:
  141. </p><pre class="screen">
  142. search_path
  143. --------------
  144. "$user", public
  145. </pre><p>
  146. The first element specifies that a schema with the same name as
  147. the current user is to be searched. If no such schema exists,
  148. the entry is ignored. The second element refers to the
  149. public schema that we have seen already.
  150. </p><p>
  151. The first schema in the search path that exists is the default
  152. location for creating new objects. That is the reason that by
  153. default objects are created in the public schema. When objects
  154. are referenced in any other context without schema qualification
  155. (table modification, data modification, or query commands) the
  156. search path is traversed until a matching object is found.
  157. Therefore, in the default configuration, any unqualified access
  158. again can only refer to the public schema.
  159. </p><p>
  160. To put our new schema in the path, we use:
  161. </p><pre class="programlisting">
  162. SET search_path TO myschema,public;
  163. </pre><p>
  164. (We omit the <code class="literal">$user</code> here because we have no
  165. immediate need for it.) And then we can access the table without
  166. schema qualification:
  167. </p><pre class="programlisting">
  168. DROP TABLE mytable;
  169. </pre><p>
  170. Also, since <code class="literal">myschema</code> is the first element in
  171. the path, new objects would by default be created in it.
  172. </p><p>
  173. We could also have written:
  174. </p><pre class="programlisting">
  175. SET search_path TO myschema;
  176. </pre><p>
  177. Then we no longer have access to the public schema without
  178. explicit qualification. There is nothing special about the public
  179. schema except that it exists by default. It can be dropped, too.
  180. </p><p>
  181. See also <a class="xref" href="functions-info.html" title="9.25. System Information Functions and Operators">Section 9.25</a> for other ways to manipulate
  182. the schema search path.
  183. </p><p>
  184. The search path works in the same way for data type names, function names,
  185. and operator names as it does for table names. Data type and function
  186. names can be qualified in exactly the same way as table names. If you
  187. need to write a qualified operator name in an expression, there is a
  188. special provision: you must write
  189. </p><pre class="synopsis">
  190. <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>
  191. </pre><p>
  192. This is needed to avoid syntactic ambiguity. An example is:
  193. </p><pre class="programlisting">
  194. SELECT 3 OPERATOR(pg_catalog.+) 4;
  195. </pre><p>
  196. In practice one usually relies on the search path for operators,
  197. so as not to have to write anything so ugly as that.
  198. </p></div><div class="sect2" id="DDL-SCHEMAS-PRIV"><div class="titlepage"><div><div><h3 class="title">5.9.4. Schemas and Privileges</h3></div></div></div><a id="id-1.5.4.11.10.2" class="indexterm"></a><p>
  199. By default, users cannot access any objects in schemas they do not
  200. own. To allow that, the owner of the schema must grant the
  201. <code class="literal">USAGE</code> privilege on the schema. To allow users
  202. to make use of the objects in the schema, additional privileges
  203. might need to be granted, as appropriate for the object.
  204. </p><p>
  205. A user can also be allowed to create objects in someone else's
  206. schema. To allow that, the <code class="literal">CREATE</code> privilege on
  207. the schema needs to be granted. Note that by default, everyone
  208. has <code class="literal">CREATE</code> and <code class="literal">USAGE</code> privileges on
  209. the schema
  210. <code class="literal">public</code>. This allows all users that are able to
  211. connect to a given database to create objects in its
  212. <code class="literal">public</code> schema.
  213. Some <a class="link" href="ddl-schemas.html#DDL-SCHEMAS-PATTERNS" title="5.9.6. Usage Patterns">usage patterns</a> call for
  214. revoking that privilege:
  215. </p><pre class="programlisting">
  216. REVOKE CREATE ON SCHEMA public FROM PUBLIC;
  217. </pre><p>
  218. (The first <span class="quote">“<span class="quote">public</span>”</span> is the schema, the second
  219. <span class="quote">“<span class="quote">public</span>”</span> means <span class="quote">“<span class="quote">every user</span>”</span>. In the
  220. first sense it is an identifier, in the second sense it is a
  221. key word, hence the different capitalization; recall the
  222. guidelines from <a class="xref" href="sql-syntax-lexical.html#SQL-SYNTAX-IDENTIFIERS" title="4.1.1. Identifiers and Key Words">Section 4.1.1</a>.)
  223. </p></div><div class="sect2" id="DDL-SCHEMAS-CATALOG"><div class="titlepage"><div><div><h3 class="title">5.9.5. The System Catalog Schema</h3></div></div></div><a id="id-1.5.4.11.11.2" class="indexterm"></a><p>
  224. In addition to <code class="literal">public</code> and user-created schemas, each
  225. database contains a <code class="literal">pg_catalog</code> schema, which contains
  226. the system tables and all the built-in data types, functions, and
  227. operators. <code class="literal">pg_catalog</code> is always effectively part of
  228. the search path. If it is not named explicitly in the path then
  229. it is implicitly searched <span class="emphasis"><em>before</em></span> searching the path's
  230. schemas. This ensures that built-in names will always be
  231. findable. However, you can explicitly place
  232. <code class="literal">pg_catalog</code> at the end of your search path if you
  233. prefer to have user-defined names override built-in names.
  234. </p><p>
  235. Since system table names begin with <code class="literal">pg_</code>, it is best to
  236. avoid such names to ensure that you won't suffer a conflict if some
  237. future version defines a system table named the same as your
  238. table. (With the default search path, an unqualified reference to
  239. your table name would then be resolved as the system table instead.)
  240. System tables will continue to follow the convention of having
  241. names beginning with <code class="literal">pg_</code>, so that they will not
  242. conflict with unqualified user-table names so long as users avoid
  243. the <code class="literal">pg_</code> prefix.
  244. </p></div><div class="sect2" id="DDL-SCHEMAS-PATTERNS"><div class="titlepage"><div><div><h3 class="title">5.9.6. Usage Patterns</h3></div></div></div><p>
  245. Schemas can be used to organize your data in many ways.
  246. A <em class="firstterm">secure schema usage pattern</em> prevents untrusted
  247. users from changing the behavior of other users' queries. When a database
  248. does not use a secure schema usage pattern, users wishing to securely
  249. query that database would take protective action at the beginning of each
  250. session. Specifically, they would begin each session by
  251. setting <code class="varname">search_path</code> to the empty string or otherwise
  252. removing non-superuser-writable schemas
  253. from <code class="varname">search_path</code>. There are a few usage patterns
  254. easily supported by the default configuration:
  255. </p><div class="itemizedlist"><ul class="itemizedlist" style="list-style-type: disc; "><li class="listitem"><p>
  256. Constrain ordinary users to user-private schemas. To implement this,
  257. issue <code class="literal">REVOKE CREATE ON SCHEMA public FROM PUBLIC</code>,
  258. and create a schema for each user with the same name as that user.
  259. Recall that the default search path starts
  260. with <code class="literal">$user</code>, which resolves to the user name.
  261. Therefore, if each user has a separate schema, they access their own
  262. schemas by default. After adopting this pattern in a database where
  263. untrusted users had already logged in, consider auditing the public
  264. schema for objects named like objects in
  265. schema <code class="literal">pg_catalog</code>. This pattern is a secure schema
  266. usage pattern unless an untrusted user is the database owner or holds
  267. the <code class="literal">CREATEROLE</code> privilege, in which case no secure
  268. schema usage pattern exists.
  269. </p><p>
  270. </p></li><li class="listitem"><p>
  271. Remove the public schema from the default search path, by modifying
  272. <a class="link" href="config-setting.html#CONFIG-SETTING-CONFIGURATION-FILE" title="19.1.2. Parameter Interaction via the Configuration File"><code class="filename">postgresql.conf</code></a>
  273. or by issuing <code class="literal">ALTER ROLE ALL SET search_path =
  274. "$user"</code>. Everyone retains the ability to create objects in
  275. the public schema, but only qualified names will choose those objects.
  276. While qualified table references are fine, calls to functions in the
  277. public schema <a class="link" href="typeconv-func.html" title="10.3. Functions">will be unsafe or
  278. unreliable</a>. If you create functions or extensions in the public
  279. schema, use the first pattern instead. Otherwise, like the first
  280. pattern, this is secure unless an untrusted user is the database owner
  281. or holds the <code class="literal">CREATEROLE</code> privilege.
  282. </p></li><li class="listitem"><p>
  283. Keep the default. All users access the public schema implicitly. This
  284. simulates the situation where schemas are not available at all, giving
  285. a smooth transition from the non-schema-aware world. However, this is
  286. never a secure pattern. It is acceptable only when the database has a
  287. single user or a few mutually-trusting users.
  288. </p></li></ul></div><p>
  289. </p><p>
  290. For any pattern, to install shared applications (tables to be used by
  291. everyone, additional functions provided by third parties, etc.), put them
  292. into separate schemas. Remember to grant appropriate privileges to allow
  293. the other users to access them. Users can then refer to these additional
  294. objects by qualifying the names with a schema name, or they can put the
  295. additional schemas into their search path, as they choose.
  296. </p></div><div class="sect2" id="DDL-SCHEMAS-PORTABILITY"><div class="titlepage"><div><div><h3 class="title">5.9.7. Portability</h3></div></div></div><p>
  297. In the SQL standard, the notion of objects in the same schema
  298. being owned by different users does not exist. Moreover, some
  299. implementations do not allow you to create schemas that have a
  300. different name than their owner. In fact, the concepts of schema
  301. and user are nearly equivalent in a database system that
  302. implements only the basic schema support specified in the
  303. standard. Therefore, many users consider qualified names to
  304. really consist of
  305. <code class="literal"><em class="replaceable"><code>user_name</code></em>.<em class="replaceable"><code>table_name</code></em></code>.
  306. This is how <span class="productname">PostgreSQL</span> will effectively
  307. behave if you create a per-user schema for every user.
  308. </p><p>
  309. Also, there is no concept of a <code class="literal">public</code> schema in the
  310. SQL standard. For maximum conformance to the standard, you should
  311. not use the <code class="literal">public</code> schema.
  312. </p><p>
  313. Of course, some SQL database systems might not implement schemas
  314. at all, or provide namespace support by allowing (possibly
  315. limited) cross-database access. If you need to work with those
  316. systems, then maximum portability would be achieved by not using
  317. schemas at all.
  318. </p></div></div><div class="navfooter"><hr /><table width="100%" summary="Navigation footer"><tr><td width="40%" align="left"><a accesskey="p" href="ddl-rowsecurity.html">Prev</a> </td><td width="20%" align="center"><a accesskey="u" href="ddl.html">Up</a></td><td width="40%" align="right"> <a accesskey="n" href="ddl-inherit.html">Next</a></td></tr><tr><td width="40%" align="left" valign="top">5.8. Row Security Policies </td><td width="20%" align="center"><a accesskey="h" href="index.html">Home</a></td><td width="40%" align="right" valign="top"> 5.10. Inheritance</td></tr></table></div></body></html>
上海开阖软件有限公司 沪ICP备12045867号-1