From 9175d7df66a6882ca94a3b1ce93bc4c56e02aa2c Mon Sep 17 00:00:00 2001 From: Tom Lane Date: Mon, 17 Jan 2005 01:29:02 +0000 Subject: [PATCH] Some more copy-editing. --- doc/src/sgml/ddl.sgml | 505 ++++++++++++++++++++++++++++---------------------- 1 file changed, 280 insertions(+), 225 deletions(-) diff --git a/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml index 3ae7d241e7..727b00f0ea 100644 --- a/doc/src/sgml/ddl.sgml +++ b/doc/src/sgml/ddl.sgml @@ -1,4 +1,4 @@ - + Data Definition @@ -163,198 +163,6 @@ 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. - - - - column - system column - - - - - oid - - - - OID - column - - 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 using 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 - - - tableoid - - - - The OID of the table containing this row. This column 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 - - - xmin - - - - The identity (transaction ID) of the inserting transaction for - this row version. (A row version is an individual state of a - row; each update of a row creates a new row version for the same - logical row.) - - - - - - cmin - - - cmin - - - - The command identifier (starting at zero) within the inserting - transaction. - - - - - - xmax - - - xmax - - - - The identity (transaction ID) of the deleting transaction, or - zero for an undeleted row version. It is possible for this column to - be nonzero in a visible row version. That usually indicates that the - deleting transaction hasn't committed yet, or that an attempted - deletion was rolled back. - - - - - - cmax - - - cmax - - - - The command identifier within the deleting transaction, or zero. - - - - - - ctid - - - ctid - - - - The physical location of the row version within its table. Note that - although the ctid can be used to - locate the row version 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. - - - - - - - OIDs are 32-bit quantities and are assigned from a single - cluster-wide counter. In a large or long-lived database, it is - possible for the counter to wrap around. Hence, it is bad - practice to assume that OIDs are unique, unless you take steps to - ensure that this is the case. If you need to identify the rows in - a table, using a sequence generator is strongly recommended. - However, OIDs can be used as well, provided that a few additional - precautions are taken: - - - - - A unique constraint should be created on the OID column of each - table for which the OID will be used to identify rows. - - - - - OIDs should never be assumed to be unique across tables; use - the combination of tableoid and row OID if you - need a database-wide identifier. - - - - - The tables in question should be created using WITH - OIDS to ensure forward compatibility with future - releases of PostgreSQL. It is - planned that WITHOUT OIDS will become the default. - - - - - - - Transaction identifiers are also 32-bit quantities. In a - long-lived database it is possible for transaction IDs to wrap - around. This is not a fatal problem given appropriate maintenance - procedures; see for details. It is - unwise, however, to depend on the uniqueness of transaction IDs - over the long term (more than one billion transactions). - - - - Command - identifiers are also 32-bit quantities. This creates a hard limit - of 232 (4 billion) SQL commands - within a single transaction. In practice this limit is not a - problem — note that the limit is on number of - SQL commands, not number of rows processed. - - - Default Values @@ -391,7 +199,7 @@ CREATE TABLE products ( - The default value may be a scalar expression, which will be + The default value may be an expression, which will be evaluated whenever the default value is inserted (not when the table is created). A common example is that a timestamp column may have a default of now(), @@ -460,9 +268,9 @@ CREATE TABLE products ( A check constraint is the most generic constraint type. It allows - you to specify that the value in a certain column must satisfy an - arbitrary expression. For instance, to require positive product - prices, you could use: + you to specify that the value in a certain column must satisfy a + Boolean (truth-value) expression. For instance, to require positive + product prices, you could use: CREATE TABLE products ( product_no integer, @@ -500,7 +308,8 @@ CREATE TABLE products ( So, to specify a named constraint, use the key word CONSTRAINT followed by an identifier followed - by the constraint definition. + by the constraint definition. (If you don't specify a constraint + name in this way, the system chooses a name for you.) @@ -513,7 +322,7 @@ CREATE TABLE products ( name text, price numeric CHECK (price > 0), discounted_price numeric CHECK (discounted_price > 0), - CHECK (price > discounted_price) + CHECK (price > discounted_price) ); @@ -529,9 +338,13 @@ CREATE TABLE products ( We say that the first two constraints are column constraints, whereas the third one is a table constraint because it is written separately - from the column definitions. Column constraints can also be + from any one column definition. Column constraints can also be written as table constraints, while the reverse is not necessarily - possible. The above example could also be written as + possible, since a column constraint is supposed to refer to only the + column it is attached to. (PostgreSQL doesn't + enforce that rule, but you should follow it if you want your table + definitions to work with other database systems.) The above example could + also be written as CREATE TABLE products ( product_no integer, @@ -556,6 +369,22 @@ CREATE TABLE products ( It's a matter of taste. + + Names can be assigned to table constraints in just the same way as + for column constraints: + +CREATE TABLE products ( + product_no integer, + name text, + price numeric, + CHECK (price > 0), + discounted_price numeric, + CHECK (discounted_price > 0), + CONSTRAINT valid_discount CHECK (price > discounted_price) +); + + + null value with check constraints @@ -564,7 +393,7 @@ CREATE TABLE products ( It should be noted that a check constraint is satisfied if the check expression evaluates to true or the null value. Since most - expressions will evaluate to the null value if one operand is null, + expressions will evaluate to the null value if any operand is null, they will not prevent null values in the constrained columns. To ensure that a column does not contain null values, the not-null constraint described in the next section can be used. @@ -608,7 +437,7 @@ CREATE TABLE products ( Of course, a column can have more than one constraint. Just write - the constraints after one another: + the constraints one after another: CREATE TABLE products ( product_no integer NOT NULL, @@ -624,7 +453,7 @@ CREATE TABLE products ( The NOT NULL constraint has an inverse: the NULL constraint. This does not mean that the column must be null, which would surely be useless. Instead, this - simply defines the default behavior that the column may be null. + simply selects the default behavior that the column may be null. The NULL constraint is not defined in the SQL standard and should not be used in portable applications. (It was only added to PostgreSQL to be @@ -695,10 +524,13 @@ CREATE TABLE example ( UNIQUE (a, c) ); + This specifies that the combination of values in the indicated columns + is unique across the whole table, though any one of the columns + need not be (and ordinarily isn't) unique. - It is also possible to assign names to unique constraints: + You can assign your own name for a unique constraint, in the usual way: CREATE TABLE products ( product_no integer CONSTRAINT must_be_different UNIQUE, @@ -857,7 +689,7 @@ CREATE TABLE orders ( CREATE TABLE orders ( order_id integer PRIMARY KEY, - product_no integer REFERENCES products, + product_no integer REFERENCES products, quantity integer ); @@ -877,11 +709,16 @@ CREATE TABLE t1 ( FOREIGN KEY (b, c) REFERENCES other_table (c1, c2) ); - Of course, the number and type of the constrained columns needs to + Of course, the number and type of the constrained columns need to match the number and type of the referenced columns. + You can assign your own name for a foreign key constraint, + in the usual way. + + + A table can contain more than one foreign key constraint. This is used to implement many-to-many relationships between tables. Say you have tables about products and orders, but now you want to @@ -907,7 +744,7 @@ CREATE TABLE order_items ( PRIMARY KEY (product_no, order_id) ); - Note also that the primary key overlaps with the foreign keys in + Notice that the primary key overlaps with the foreign keys in the last table. @@ -1004,6 +841,198 @@ CREATE TABLE order_items ( + + 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. + + + + column + system column + + + + + oid + + + + OID + column + + 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 using 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 + + + tableoid + + + + The OID of the table containing this row. This column 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 + + + xmin + + + + The identity (transaction ID) of the inserting transaction for + this row version. (A row version is an individual state of a + row; each update of a row creates a new row version for the same + logical row.) + + + + + + cmin + + + cmin + + + + The command identifier (starting at zero) within the inserting + transaction. + + + + + + xmax + + + xmax + + + + The identity (transaction ID) of the deleting transaction, or + zero for an undeleted row version. It is possible for this column to + be nonzero in a visible row version. That usually indicates that the + deleting transaction hasn't committed yet, or that an attempted + deletion was rolled back. + + + + + + cmax + + + cmax + + + + The command identifier within the deleting transaction, or zero. + + + + + + ctid + + + ctid + + + + The physical location of the row version within its table. Note that + although the ctid can be used to + locate the row version 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. + + + + + + + OIDs are 32-bit quantities and are assigned from a single + cluster-wide counter. In a large or long-lived database, it is + possible for the counter to wrap around. Hence, it is bad + practice to assume that OIDs are unique, unless you take steps to + ensure that this is the case. If you need to identify the rows in + a table, using a sequence generator is strongly recommended. + However, OIDs can be used as well, provided that a few additional + precautions are taken: + + + + + A unique constraint should be created on the OID column of each + table for which the OID will be used to identify rows. + + + + + OIDs should never be assumed to be unique across tables; use + the combination of tableoid and row OID if you + need a database-wide identifier. + + + + + The tables in question should be created using WITH + OIDS to ensure forward compatibility with future + releases of PostgreSQL. It is + planned that WITHOUT OIDS will become the default. + + + + + + + Transaction identifiers are also 32-bit quantities. In a + long-lived database it is possible for transaction IDs to wrap + around. This is not a fatal problem given appropriate maintenance + procedures; see for details. It is + unwise, however, to depend on the uniqueness of transaction IDs + over the long term (more than one billion transactions). + + + + Command + identifiers are also 32-bit quantities. This creates a hard limit + of 232 (4 billion) SQL commands + within a single transaction. In practice this limit is not a + problem — note that the limit is on number of + SQL commands, not number of rows processed. + + + Inheritance @@ -1118,7 +1147,7 @@ SET SQL_Inheritance TO OFF; In some cases you may wish to know which table a particular row originated from. There is a system column called - TABLEOID in each table which can tell you the + tableoid in each table which can tell you the originating table: @@ -1223,13 +1252,15 @@ WHERE c.altitude > 500 and c.tableoid = p.oid; When you create a table and you realize that you made a mistake, or - the requirements of the application changed, then you can drop the + the requirements of the application change, then you can drop the table and create it again. But this is not a convenient option if the table is already filled with data, or if the table is referenced by other database objects (for instance a foreign key constraint). Therefore PostgreSQL - provides a family of commands to make modifications on existing - tables. + provides a family of commands to make modifications to existing + tables. Note that this is conceptually distinct from altering + the data contained in the table: here we are interested in altering + the definition, or structure, of the table. @@ -1275,7 +1306,7 @@ WHERE c.altitude > 500 and c.tableoid = p.oid; - To add a column, use this command: + To add a column, use a command like this: ALTER TABLE products ADD COLUMN description text; @@ -1307,10 +1338,21 @@ ALTER TABLE products ADD COLUMN description text CHECK (description <> '') - To remove a column, use this command: + To remove a column, use a command like this: ALTER TABLE products DROP COLUMN description; + Whatever data was in the column disappears. Table constraints involving + the column are dropped, too. However, if the column is referenced by a + foreign key constraint of another table, + PostgreSQL will not silently drop that + constraint. You can authorize dropping everything that depends on + the column by adding CASCADE: + +ALTER TABLE products DROP COLUMN description CASCADE; + + See for a description of the general + mechanism behind this. @@ -1367,6 +1409,13 @@ ALTER TABLE products DROP CONSTRAINT some_name; + As with dropping a column, you need to add CASCADE if you + want to drop a constraint that something else depends on. An example + is that a foreign key constraint depends on a unique or primary key + constraint on the referenced column(s). + + + This works the same for all constraint types except not-null constraints. To drop a not null constraint use @@ -1398,7 +1447,7 @@ ALTER TABLE products ALTER COLUMN price SET DEFAULT 7.77; ALTER TABLE products ALTER COLUMN price DROP DEFAULT; - This is equivalent to setting the default to null. + This is effectively the same as setting the default to null. As a consequence, it is not an error to drop a default where one hadn't been defined, because the default is implicitly the null value. @@ -1660,6 +1709,9 @@ CREATE SCHEMA myschema; schema.table + 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.) @@ -1669,9 +1721,9 @@ CREATE SCHEMA myschema; 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. + 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. @@ -1681,9 +1733,6 @@ 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. @@ -1844,7 +1893,7 @@ SET search_path TO myschema; - See also for other ways to access + See also for other ways to manipulate the schema search path. @@ -2044,7 +2093,13 @@ REVOKE CREATE ON SCHEMA public FROM PUBLIC; - Functions, operators, data types, domains + Functions and operators + + + + + + Data types and domains @@ -2120,7 +2175,7 @@ DROP TABLE products CASCADE; According to the SQL standard, specifying either RESTRICT or CASCADE is - required. No database system actually implements it that way, but + required. No database system actually enforces that rule, but whether the default behavior is RESTRICT or CASCADE varies across systems. @@ -2132,7 +2187,7 @@ DROP TABLE products CASCADE; from PostgreSQL versions prior to 7.3 are not maintained or created during the upgrade process. All other dependency types will be properly - created during an upgrade. + created during an upgrade from a pre-7.3 database. -- 2.11.0