diff --git a/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml index 49fb9784b1..85ba27b3ce 100644 --- a/doc/src/sgml/ddl.sgml +++ b/doc/src/sgml/ddl.sgml @@ -1,4 +1,4 @@ - + Data Definition @@ -151,7 +151,7 @@ DROP TABLE products; columns will be filled with their respective default values. A data manipulation command can also request explicitly that a column be set to its default value, without knowing what this value is. - (Details about data manipulation commands are in the next chapter.) + (Details about data manipulation commands are in .) @@ -263,7 +263,7 @@ CREATE TABLE products ( The first two constraints should look familiar. The third one uses a new syntax. It is not attached to a particular column, instead it appears as a separate item in the comma-separated - column list. In general, column definitions and constraint + column list. Column definitions and these constraint definitions can be listed in mixed order. @@ -299,8 +299,10 @@ CREATE TABLE products ( It should be noted that a check constraint is satisfied if the - check expression evaluates to true or the null value. To ensure - that a column does not contain null values, the not-null + check expression evaluates to true or the null value. Since most + expressions will evaluate to the null value if one 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 should be used. @@ -322,12 +324,13 @@ CREATE TABLE products ( A not-null constraint is always written as a column constraint. A - not-null constraint is equivalent to creating a check constraint - CHECK (column_name IS NOT - NULL), but in PostgreSQL - creating an explicit not-null constraint is more efficient. The - drawback is that you cannot give explicit names to not-null - constraints created that way. + not-null constraint is functionally equivalent to creating a check + constraint CHECK (column_name + IS NOT NULL), but in + PostgreSQL creating an explicit + not-null constraint is more efficient. The drawback is that you + cannot give explicit names to not-null constraints created that + way. @@ -564,8 +567,8 @@ CREATE TABLE t1 ( FOREIGN KEY (b, c) REFERENCES other_table (c1, c2) ); - Of course, the number and type of constrained columns needs to - match the number and type of referenced columns. + Of course, the number and type of the constrained columns needs to + match the number and type of the referenced columns. @@ -847,13 +850,14 @@ SET SQL_Inheritance TO OFF; Modifying Tables - When you create a table and you realize that you made a mistake, - 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. + 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 + 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. @@ -862,6 +866,9 @@ SET SQL_Inheritance TO OFF; Add columns, + + Remove a column, + Add constraints, @@ -879,22 +886,135 @@ SET SQL_Inheritance TO OFF; - In the current implementation you cannot - - - Remove a column, - - - Change the data type of a column. - - - These may be possible in a future release. + All these actions are performed using the ALTER + TABLE command. - - OK, now explain how to do this. There's currently so much activity - on ALTER TABLE that I'm holding off a bit. - + + Adding a Column + + + To add a column, use this command: + +ALTER TABLE products ADD COLUMN description text; + + The new column will initially be filled with null values in the + existing rows of the table. + + + + You can also define a constraint on the column at the same time, + using the usual syntax: + +ALTER TABLE products ADD COLUMN description text CHECK (description <> ''); + + A new column cannot have a not-null constraint since the column + initially has to contain null values. But you can add a not-null + constraint later. Also, you cannot define a default value on a + new column. According to the SQL standard, this would have to + fill the new columns in the existing rows with the default value, + which is not implemented yet. But you can adjust the column + default later on. + + + + + Removing a Column + + + To remove a column, use this command: + +ALTER TABLE products DROP COLUMN description; + + + + + + Adding a Constraint + + + To add a constraint, the table constraint syntax is used. For example: + +ALTER TABLE products ADD CHECK (name <> ''); +ALTER TABLE products ADD CONSTRAINT some_name UNIQUE (product_no); +ALTER TABLE products ADD FOREIGN KEY (product_group_id) REFERENCES product_groups; + + To add a not-null constraint, which cannot be written as a table + constraint, use this syntax: + +ALTER TABLE products ALTER COLUMN product_no SET NOT NULL; + + + + + The constraint will be checked immediately, so the table data must + satisfy the constraint before it can be added. + + + + + Removing a Constraint + + + To remove a constraint you need to know its name. If you gave it + a name then that's easy. Otherwise the system assigned a + generated name, which you need to find out. The + psql command \d + tablename can be helpful + here; other interfaces might also provide a way to inspect table + details. Then the command is: + +ALTER TABLE products DROP CONSTRAINT some_name; + + This works the same for all constraint types except not-null + constraints. To drop a not null constraint use + +ALTER TABLE products ALTER COLUMN product_no DROP NOT NULL; + + (Recall that not-null constraints do not have names.) + + + + + Changing the Default + + + To set a new default for a column, use a command like this: + +ALTER TABLE products ALTER COLUMN price SET DEFAULT 7.77; + + To remove any default value, use + +ALTER TABLE products ALTER COLUMN price DROP DEFAULT; + + This is equivalent to setting the default to null, at least in + PostgreSQL. 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. + + + + + Renaming a Column + + + To rename a column: + +ALTER TABLE products RENAME COLUMN product_no TO product_number; + + + + + + Renaming a Table + + + To rename a table: + +ALTER TABLE products RENAME TO items; + + + @@ -990,10 +1110,10 @@ DROP TABLE products CASCADE; - Foreign Key constraint dependencies and SERIAL dependencies from - PostgreSQL versions prior to 7.3 are - not maintained or created during the upgrade - process. However, all other dependency types are created successfully. + Foreign key constraint dependencies and serial column dependencies + from PostgreSQL versions prior to 7.3 + are not maintained or created during the + upgrade process. All other dependency types survive the upgrade.