diff --git a/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml index 85ba27b3ce..ff40feeac9 100644 --- a/doc/src/sgml/ddl.sgml +++ b/doc/src/sgml/ddl.sgml @@ -1,4 +1,4 @@ - + Data Definition @@ -142,6 +142,120 @@ DROP TABLE products; + + System Columns + + + Every table has several system columns that are + implicitly defined by the system. Therefore, these names cannot be + used as names of user-defined columns. (Note that these + restrictions are separate from whether the name is a key word or + not; quoting a name will not allow you to escape these + restrictions.) You do not really need to be concerned about these + columns, just know they exist. + + + + columns + system columns + + + + + oid + + + + OID + + The object identifier (object ID) of a row. This is a serial + number that is automatically added by + PostgreSQL to all table rows (unless + the table was created WITHOUT OIDS, in which + case this column is not present). This column is of type + oid (same name as the column); see for more information about the type. + + + + + + tableoid + + + The OID of the table containing this row. This attribute is + particularly handy for queries that select from inheritance + hierarchies, since without it, it's difficult to tell which + individual table a row came from. The + tableoid can be joined against the + oid column of + pg_class to obtain the table name. + + + + + + xmin + + + The identity (transaction ID) of the inserting transaction for + this tuple. (Note: In this context, a tuple is an individual + state of a row; each update of a row creates a new tuple for the + same logical row.) + + + + + + cmin + + + The command identifier (starting at zero) within the inserting + transaction. + + + + + + xmax + + + The identity (transaction ID) of the deleting transaction, or + zero for an undeleted tuple. It is possible for this field to + be nonzero in a visible tuple: that usually indicates that the + deleting transaction hasn't committed yet, or that an attempted + deletion was rolled back. + + + + + + cmax + + + The command identifier within the deleting transaction, or zero. + + + + + + ctid + + + The physical location of the tuple within its table. Note that + although the ctid can be used to + locate the tuple very quickly, a row's + ctid will change each time it is + updated or moved by VACUUM FULL. Therefore + ctid is useless as a long-term row + identifier. The OID, or even better a user-defined serial + number, should be used to identify logical rows. + + + + + + Default Values @@ -1016,11 +1130,502 @@ ALTER TABLE products RENAME TO items; + + + Privileges + + + When you create a database object, you become its owner. By + default, only the owner of an object can do anything with the + object. In order to allow other users to use it, + privileges must be granted. (There are also + users that have the superuser privilege. Those users can always + access any object.) + + + + + To change the owner of a table, index, sequence, or view, use the + ALTER TABLE command. + + + + + There are several different privileges: SELECT, + INSERT, UPDATE, DELETE, + RULE, REFERENCES, TRIGGER, + CREATE, TEMPORARY, EXECUTE, + USAGE, and ALL PRIVILEGES. For complete + information on the different types of privileges supported by + PostgreSQL, refer to the + GRANT reference page. The following sections + and chapters will also show you how those privileges are used. + + + + The right to modify or destroy an object is always the privilege of + the owner only. + + + + To assign privileges, the GRANT command is + used. So, if joe is an existing user, and + accounts is an existing table, the privilege to + update the table can be granted with + +GRANT UPDATE ON accounts TO joe; + + The user executing this command must be the owner of the table. To + grant a privilege to a group, use + +GRANT SELECT ON accounts TO GROUP staff; + + The special user name PUBLIC can + be used to grant a privilege to every user on the system. Writing + ALL in place of a specific privilege specifies that all + privileges will be granted. + + + + To revoke a privilege, use the fittingly named + REVOKE command: + +REVOKE ALL ON accounts FROM PUBLIC; + + The special privileges of the table owner (i.e., the right to do + DROP, GRANT, REVOKE, etc) + are always implicit in being the owner, + and cannot be granted or revoked. But the table owner can choose + to revoke his own ordinary privileges, for example to make a + table read-only for himself as well as others. + + Schemas - to be filled in + + schemas + + + + namespaces + + + + A PostgreSQL database cluster (installation) + 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. + + + + + 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, joe in two databases + in the same cluster; but the system can be configured to allow + joe access to only some of the databases. + + + + + A database contains one or more named schemas, 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 schema1 and myschema may + contain tables named mytable. 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. + + + + There are several reasons why one might want to use schemas: + + + + + To allow many users to use one database without interfering with + each other. + + + + + + To organize database objects into logical groups to make them + more manageable. + + + + + + Third-party applications can be put into separate schemas so + they cannot collide with the names of other objects. + + + + + Schemas are analogous to directories at the operating system level, + but schemas cannot be nested. + + + + Creating a Schema + + + To create a separate schema, use the command CREATE + SCHEMA. Give the schema a name of your choice. For + example: + +CREATE SCHEMA myschema; + + + + + qualified names + + + + names + qualified + + + + To create or access objects in a schema, write a + qualified name consisting of the schema name and + table name separated by a dot: + +schema.table + + Actually, the even more general syntax + +database.schema.table + + can be used too, but at present this is just for pro-forma compliance + with the SQL standard; if you write a database name it must be the + same as the database you are connected to. + + + + So to create a table in the new schema, use + +CREATE TABLE myschema.mytable ( + ... +); + + This works anywhere a table name is expected, including the table + modification commands and the data access commands discussed in + the following chapters. + + + + To drop a schema if it's empty (all objects in it have been + dropped), use + +DROP SCHEMA myschema; + + To drop a schema including all contained objects, use + +DROP SCHEMA myschema CASCADE; + + See for a description of the general + mechanism behind this. + + + + 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: + +CREATE SCHEMA schemaname AUTHORIZATON username; + + You can even omit the schema name, in which case the schema name + will be the same as the user name. See for how this can be useful. + + + + Schema names beginning with pg_ are reserved for + system purposes and may not be created by users. + + + + + The Public Schema + + + In the previous sections we created tables without specifying any + schema names. Those tables (and other objects) are automatically + put into a schema named public. Every new database + contains such a schema. Thus, the following are equivalent: + +CREATE TABLE products ( ... ); + + and + +CREATE TABLE public.products ( ... ); + + + + + + The Schema Search Path + + + search path + + + + unqualified names + + + + names + unqualified + + + + 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 unqualified names, + which consist of just the table name. The system determines which table + is meant by following a search path, 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. + + + + 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 CREATE TABLE + command does not specify a schema name. + + + + To show the current search path, use the following command: + +SHOW search_path; + + In the default setup this returns: + + search_path +-------------- + $user,public + + The first element specifies that a schema with the same name as + the current user is to be searched. Since no such schema exists + yet, this entry is ignored. The second element refers to the + public schema that we have seen already. + + + + The first schema in the seach 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. + + + + To put our new schema in the path, we use + +SET search_path TO myschema,public; + + (We omit the $user here because we have no + immediate need for it.) And then we can access the table without + schema qualification: + +DROP TABLE mytable; + + Also, since myschema is the first element in + the path, new objects would by default be created in it. + + + + We could also have written + +SET search_path TO myschema; + + 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. + + + + See also for other ways to access + the schema search path. + + + + The search path works in the same way for datatype names, function names, + and operator names as it does for table names. Datatype 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 + +OPERATOR(schema.operator) + + This is needed to avoid syntactic ambiguity. An example is + +SELECT 3 OPERATOR(pg_catalog.+) 4; + + In practice one usually relies on the search path for operators, + so as not to have to write anything so ugly as that. + + + + + Schemas and Privileges + + + By default, users cannot see the objects in schemas they do not + own. To allow that, the owner of the schema needs to grant the + USAGE 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. + + + + A user can also be allowed to create objects in someone else's + schema. To allow that, the CREATE privilege on + the schema needs to be granted. Note that by default, everyone + has the CREATE privilege on the schema + public. This allows all users that manage to + connect to a given database to create objects there. If you do + not want to allow that, you can revoke that privilege: + +REVOKE CREATE ON public FROM PUBLIC; + + (The first public is the schema, the second + public means every user. In the + first sense it is an identifier, in the second sense it is a + reserved word, hence the different capitalization; recall the + guidelines from .) + + + + + The System Catalog Schema + + + In addition to public and user-created schemas, each + database contains a pg_catalog schema, which contains + the system tables and all the built-in datatypes, functions, and + operators. pg_catalog is always effectively part of + the search path. If it is not named explicitly in the path then + it is implicitly searched before searching the path's + schemas. This ensures that built-in names will always be + findable. However, you may explicitly place + pg_catalog at the end of your search path if you + prefer to have user-defined names override built-in names. + + + + In PostgreSQL versions before 7.3, + table names beginning with pg_ 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 catalog named the same as your + table. (With the default search path, an unqualified reference to + your table name would be resolved as the system catalog instead.) + System catalogs will continue to follow the convention of having + names beginning with pg_, so that they will not + conflict with unqualified user-table names so long as users avoid + the pg_ prefix. + + + + + Usage Patterns + + + Schemas can be used to organize your data in many ways. There are + a few usage patterns are recommended and are easily supported by + the default configuration: + + + + 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 few cooperating + users in a database. This setup also allows smooth transition + from the non-schema-aware world. + + + + + + You can create a schema for each user with the same name as + that user. Recall that the default search path starts with + $user, which resolves to the user name. + Therefore, if each user has a separate schema, they access their + own schemas by default. + + + + 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. + + + + + + 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 object by qualifying the names + with a schema name, or they can put the additional schemas into + their path, as they choose. + + + + + + + + Portability + + + In the SQL standard, the notion of objects in the same schema + being owned by different users does not exist. Moreover, some + implementations don't 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 + username.tablename. + This is also supported by PostgreSQL if you create a per-user + schema for every user. + + + + Also, there is no concept of a public schema in the + SQL standard. For maximum conformance to the standard, you should + not use (perhaps even remove) the public schema. + + + + 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. + + diff --git a/doc/src/sgml/syntax.sgml b/doc/src/sgml/syntax.sgml index 341df4973a..72ce0880fb 100644 --- a/doc/src/sgml/syntax.sgml +++ b/doc/src/sgml/syntax.sgml @@ -1,5 +1,5 @@ @@ -581,7 +581,7 @@ CAST ( 'string' AS type ) The period (.) is used in floating-point - constants, and to separate table and column names. + constants, and to separate schema, table, and column names. @@ -815,307 +815,6 @@ SELECT 3 OPERATOR(pg_catalog.+) 4; - - Schemas and Naming Conventions - - - schemas - - - - search path - - - - namespaces - - - - A PostgreSQL database cluster (installation) - 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. - - - - - 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, joe in two databases - in the same cluster; but the system can be configured to allow - joe access to only some of the databases. - - - - - Schema Object Names - - - A database contains one or more named schemas, which - in turn contain tables. Schemas also contain other kinds of named - objects, including datatypes, functions, and operators. The same - object name can be used in different schemas without conflict; for - example, both schema1 and myschema may - contain tables named mytable. 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. - - - - qualified names - - - - names - qualified - - - - To name a table precisely, write a qualified name consisting - of the schema name and table name separated by a dot: - - schema.table - - Actually, the even more general syntax - - database.schema.table - - can be used too, but at present this is just for pro-forma compliance - with the SQL standard; if you write a database name it must be the - same as the database you are connected to. - - - - unqualified names - - - - names - unqualified - - - - 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 unqualified names, - which consist of just the table name. The system determines which table - is meant by following a search path, 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. - - - - 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 CREATE TABLE - command does not specify a schema name. - - - - The search path works in the same way for datatype names, function names, - and operator names as it does for table names. Datatype 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 - -OPERATOR(schema.operator) - - This is needed to avoid syntactic ambiguity. An example is - -SELECT 3 OPERATOR(pg_catalog.+) 4; - - In practice one usually relies on the search path for operators, - so as not to have to write anything so ugly as that. - - - - The standard search path in PostgreSQL - contains first the schema having the same name as the session user - (if it exists), and second the schema named public - (if it exists, which it does by default). This arrangement allows - a flexible combination of private and shared tables. If no per-user - schemas are created then all user tables will exist in the shared - public schema, providing behavior that is backwards-compatible - with pre-7.3 PostgreSQL releases. - - - - - There is no concept of a public schema in the SQL standard. - To achieve closest conformance to the standard, the DBA should - create per-user schemas for every user, and not use (perhaps even - remove) the public schema. - - - - - In addition to public and user-created schemas, each database - contains a - pg_catalog schema, which contains the system tables - and all the built-in datatypes, functions, and operators. - pg_catalog is always effectively part of the search path. - If it is not named explicitly in the path then it is implicitly searched - before searching the path's schemas. This ensures that - built-in names will always be findable. However, you may explicitly - place pg_catalog at the end of your search path if you - prefer to have user-defined names override built-in names. - - - - The search path is determined by the GUC variable SEARCH_PATH and - may be changed at any time. See . - - - - - Reserved names - - - reserved names - - - - names - reserved - - - - There are several restrictions on the names that can be chosen for - user-defined database objects. These restrictions vary depending - on the kind of object. (Note that these restrictions are - separate from whether the name is a key word or not; quoting a - name will not allow you to escape these restrictions.) - - - - Schema names beginning with pg_ are reserved for system - purposes and may not be created by users. - - - - In PostgreSQL versions before 7.3, table - names beginning with pg_ 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 catalog named the same as your table. (With the - default search path, an unqualified reference to your table name - would be resolved as the system catalog instead.) System catalogs will - continue to follow the convention of having names beginning with - pg_, so that they will not conflict with unqualified - user-table names so long as users avoid the pg_ prefix. - - - - Every table has several system columns that are - implicitly defined by the system. Therefore, these names cannot - be used as names of user-defined columns: - - - columns - system columns - - - - - oid - - - - OID - - The object identifier (object ID) of a row. This is a serial number - that is automatically added by PostgreSQL to all table rows (unless - the table was created WITHOUT OIDS, in which case this column is - not present). See for more info. - - - - - - tableoid - - - The OID of the table containing this row. This attribute is - particularly handy for queries that select from inheritance - hierarchies, since without it, it's difficult to tell which - individual table a row came from. The - tableoid can be joined against the - oid column of - pg_class to obtain the table name. - - - - - - xmin - - - The identity (transaction ID) of the inserting transaction for - this tuple. (Note: A tuple is an individual state of a row; - each update of a row creates a new tuple for the same logical row.) - - - - - - cmin - - - The command identifier (starting at zero) within the inserting - transaction. - - - - - - xmax - - - The identity (transaction ID) of the deleting transaction, - or zero for an undeleted tuple. It is possible for this field - to be nonzero in a visible tuple: that usually indicates that the - deleting transaction hasn't committed yet, or that an attempted - deletion was rolled back. - - - - - - cmax - - - The command identifier within the deleting transaction, or zero. - - - - - - ctid - - - The physical location of the tuple within its table. - Note that although the ctid - can be used to locate the tuple very quickly, a row's - ctid will change each time it is updated - or moved by VACUUM FULL. - Therefore ctid is useless as a long-term - row identifier. - The OID, or even better a user-defined serial number, should - be used to identify logical rows. - - - - - - - - Value Expressions diff --git a/doc/src/sgml/typeconv.sgml b/doc/src/sgml/typeconv.sgml index 58427d205d..0bfc40b1ed 100644 --- a/doc/src/sgml/typeconv.sgml +++ b/doc/src/sgml/typeconv.sgml @@ -232,7 +232,7 @@ Select the operators to be considered from the pg_operator system catalog. If an unqualified operator name is used (the usual case), the operators considered are those of the right name and argument count that are -visible in the current search path (see ). +visible in the current search path (see ). If a qualified operator name was given, only operators in the specified schema are considered. @@ -497,7 +497,7 @@ Select the functions to be considered from the pg_proc system catalog. If an unqualified function name is used, the functions considered are those of the right name and argument count that are -visible in the current search path (see ). +visible in the current search path (see ). If a qualified function name was given, only functions in the specified schema are considered. diff --git a/doc/src/sgml/user-manag.sgml b/doc/src/sgml/user-manag.sgml index 27a6512174..70a4aba94b 100644 --- a/doc/src/sgml/user-manag.sgml +++ b/doc/src/sgml/user-manag.sgml @@ -1,5 +1,5 @@ @@ -139,6 +139,8 @@ ALTER GROUP name DROP USER uname1 Privileges + Being moved to User's Guide. Will eventually disappear here. + When a database object is created, it is assigned an owner. The owner is the user that executed the creation statement. To change