INCREMENT
Option
The optional INCREMENT
clause allows you to specify another non-zero step value than 1.
Warning
|
The SQL standard specifies that if |
Renaming a Column: the TO Clause
Changing the Data Type of a Column: the TYPE Clause
Changing the Position of a Column: the POSITION Clause
The DROP DEFAULT and SET DEFAULT Clauses
The SET NOT NULL and DROP NOT NULL Clauses
The COMPUTED [BY] or GENERATED ALWAYS AS Clauses
INCREMENT
OptionThe optional INCREMENT
clause allows you to specify another non-zero step value than 1.
Warning
|
The SQL standard specifies that if |
Computed columns can be defined with the COMPUTED [BY]
or GENERATED ALWAYS AS
clause (the SQL standard alternative to COMPUTED [BY]
).Specifying the data type is optional;if not specified, the appropriate type will be derived from the expression.
If the data type is explicitly specified for a calculated field, the calculation result is converted to the specified type.This means, for instance, that the result of a numeric expression could be converted to a string.
In a query that selects a computed column, the expression is evaluated for each row of the selected data.
Tip
|
Instead of a computed column, in some cases it makes sense to use a regular column whose value is calculated in triggers for adding and updating data.It may reduce the performance of inserting/updating records, but it will increase the performance of data selection. |
If the column is to be an array, the base type can be any SQL data type except BLOB
and array.
The dimensions of the array are specified between square brackets.
For each array dimension, one or two integer numbers define the lower and upper boundaries of its index range:
By default, arrays are 1-based.The lower boundary is implicit and only the upper boundary need be specified.A single number smaller than 1 defines the range num…1 and a number greater than 1 defines the range 1…num.
Two numbers separated by a colon (‘:
’) and optional whitespace, the second greater than the first, can be used to define the range explicitly.One or both boundaries can be less than zero, as long as the upper boundary is greater than the lower.
When the array has multiple dimensions, the range definitions for each dimension must be separated by commas and optional whitespace.
Subscripts are validated only if an array actually exists.It means that no error messages regarding invalid subscripts will be returned if selecting a specific element returns nothing or if an array field is NULL
.
Five types of constraints can be specified.They are:
Primary key (PRIMARY KEY
)
Unique key (UNIQUE
)
Foreign key (REFERENCES
)
CHECK
constraint (CHECK
)
NOT NULL
constraint (NOT NULL
)
Constraints can be specified at column level (“column constraints”) or at table level (“table constraints”).Table-level constraints are required when keys (unique constraint, primary key, foreign key) consist of multiple columns and when a CHECK
constraint involves other columns in the row besides the column being defined.The NOT NULL
constraint can only be specified as a column constraint.Syntax for some types of constraint may differ slightly according to whether the constraint is defined at the column or table level.
A column-level constraint is specified during a column definition, after all column attributes except COLLATION
are specified, and can involve only the column specified in that definition
A table-level constraints can only be specified after the definitions of the columns used in the constraint.
Table-level constraints are a more flexible way to set constraints, since they can cater for constraints involving multiple columns
You can mix column-level and table-level constraints in the same CREATE TABLE
statement
The system automatically creates the corresponding index for a primary key (PRIMARY KEY
), a unique key (UNIQUE
), and a foreign key (REFERENCES
for a column-level constraint, FOREIGN KEY REFERENCES
for table-level).
Constraints and their indexes are named automatically if no name was specified using the CONSTRAINT
clause:
The constraint name has the form INTEG_n
, where n represents one or more digits
The index name has the form RDB$PRIMARYn
(for a primary key index), RDB$FOREIGNn
(for a foreign key index) or RDB$n
(for a unique key index).
A constraint can be named explicitly if the CONSTRAINT
clause is used for its definition.By default, the constraint index will have the same name as the constraint.If a different name is wanted for the constraint index, a USING
clause can be included.
USING
ClauseThe USING
clause allows you to specify a user-defined name for the index that is created automatically and, optionally, to define the direction of the index — either ascending (the default) or descending.
PRIMARY KEY
The PRIMARY KEY
constraint is built on one or more key columns, where each column has the NOT NULL
constraint specified.The values across the key columns in any row must be unique.A table can have only one primary key.
A single-column primary key can be defined as a column-level or a table-level constraint
A multi-column primary key must be specified as a table-level constraint
UNIQUE
ConstraintThe UNIQUE
constraint defines the requirement of content uniqueness for the values in a key throughout the table.A table can contain any number of unique key constraints.
As with the primary key, the unique constraint can be multi-column.If so, it must be specified as a table-level constraint.
NULL
in Unique KeysFirebird’s SQL-compliant rules for UNIQUE
constraints allow one or more NULL
s in a column with a UNIQUE
constraint.This makes it possible to define a UNIQUE
constraint on a column that does not have the NOT NULL
constraint.
For UNIQUE
keys that span multiple columns, the logic is a little complicated:
Multiple rows having null in all the columns of the key are allowed
Multiple rows having keys with different combinations of nulls and non-null values are allowed
Multiple rows having the same key columns null and the rest filled with non-null values are allowed, provided the non-null values differ in at least one column
Multiple rows having the same key columns null and the rest filled with non-null values that are the same in every column will violate the constraint
The rules for uniqueness can be summarised thus:
In principle, all nulls are considered distinct.
However, if two rows have exactly the same key columns filled with non-null values, the NULL
columns are ignored and the uniqueness is determined on the non-null columns as though they constituted the entire key.
RECREATE TABLE t( x int, y int, z int, unique(x,y,z));
INSERT INTO t values( NULL, 1, 1 );
INSERT INTO t values( NULL, NULL, 1 );
INSERT INTO t values( NULL, NULL, NULL );
INSERT INTO t values( NULL, NULL, NULL ); -- Permitted
INSERT INTO t values( NULL, NULL, 1 ); -- Not permitted
FOREIGN KEY
A foreign key ensures that the participating column(s) can contain only values that also exist in the referenced column(s) in the master table.These referenced columns are often called target columns.They must be the primary key or a unique key in the target table.They need not have a NOT NULL
constraint defined on them although, if they are the primary key, they will, of course, have that constraint.
The foreign key columns in the referencing table itself do not require a NOT NULL
constraint.
A single-column foreign key can be defined in the column declaration, using the keyword REFERENCES
:
... ,
ARTIFACT_ID INTEGER REFERENCES COLLECTION (ARTIFACT_ID),
The column ARTIFACT_ID
in the example references a column of the same name in the table COLLECTIONS
.
Both single-column and multi-column foreign keys can be defined at the table level.For a multi-column foreign key, the table-level declaration is the only option.
...
CONSTRAINT FK_ARTSOURCE FOREIGN KEY(DEALER_ID, COUNTRY)
REFERENCES DEALER (DEALER_ID, COUNTRY),
Notice that the column names in the referenced (“master”) table may differ from those in the foreign key.
Note
|
If no target columns are specified, the foreign key automatically references the target table’s primary key. |
With the sub-clauses ON UPDATE
and ON DELETE
it is possible to specify an action to be taken on the affected foreign key column(s) when referenced values in the master table are changed:
NO ACTION
(the default) — Nothing is done
CASCADE
The change in the master table is propagated to the corresponding row(s) in the child table.If a key value changes, the corresponding key in the child records changes to the new value;if the master row is deleted, the child records are deleted.
SET DEFAULT
The foreign key columns in the affected rows will be set to their default values as they were when the foreign key constraint was defined.
SET NULL
The foreign key columns in the affected rows will be set to NULL
.
The specified action, or the default NO ACTION
, could cause a foreign key column to become invalid.For example, it could get a value that is not present in the master table.Such condition will cause the operation on the master table to fail with an error message.
...
CONSTRAINT FK_ORDERS_CUST
FOREIGN KEY (CUSTOMER) REFERENCES CUSTOMERS (ID)
ON UPDATE CASCADE ON DELETE SET NULL
CHECK
ConstraintThe CHECK
constraint defines the condition the values inserted in this column or row must satisfy.A condition is a logical expression (also called a predicate) that can return the TRUE
, FALSE
and UNKNOWN
values.A condition is considered satisfied if the predicate returns TRUE
or value UNKNOWN
(equivalent to NULL
).If the predicate returns FALSE
, the value will not be accepted.This condition is used for inserting a new row into the table (the INSERT
statement) and for updating the existing value of the table column (the UPDATE
statement) and also for statements where one of these actions may take place (UPDATE OR INSERT
, MERGE
).
Important
|
A |
CHECK
constraints — whether defined at table level or column level — refer to table columns by their names.The use of the keyword VALUE
as a placeholder — as in domain CHECK
constraints — is not valid in the context of defining constraints in a table.
with two column-level constraints and one at table-level:
CREATE TABLE PLACES (
...
LAT DECIMAL(9, 6) CHECK (ABS(LAT) <= 90),
LON DECIMAL(9, 6) CHECK (ABS(LON) <= 180),
...
CONSTRAINT CHK_POLES CHECK (ABS(LAT) < 90 OR LON = 0)
);
NOT NULL
ConstraintIn Firebird, columns are nullable by default.The NOT NULL
constraint specifies that the column cannot take NULL
in place of a value.
A NOT NULL
constraint can only be defined as a column constraint, not as a table constraint.
SQL SECURITY
ClauseThe SQL SECURITY
clause specifies the security context for executing functions referenced in computed columns, and check constraints, and the default context used for triggers fired for this table.When SQL Security is not specified, the default value of the database is applied at runtime.
See also SQL Security in chapter Security.
When the database has been configured using ALTER DATABASE INCLUDE ALL TO PUBLICATION
, new tables will automatically be added for publication, unless overridden using the DISABLE PUBLICATION
clause.
If the database has not been configured for INCLUDE ALL
(or has later been reconfigured using ALTER DATABASE EXCLUDE ALL FROM PUBLICATION
), new tables will not automatically be added for publication.To include tables for publication, the ENABLE PUBLICATION
clause must be used.
ALTER TABLE
Alters a table
DSQL, ESQL
ALTER TABLE tablename
<operation> [, <operation> ...]
<operation> ::=
ADD <col_def>
| ADD <tconstraint>
| DROP colname
| DROP CONSTRAINT constr_name
| ALTER [COLUMN] colname <col_mod>
| ALTER SQL SECURITY {INVOKER | DEFINER}
| DROP SQL SECURITY
| {ENABLE | DISABLE} PUBLICATION
<col_mod> ::=
TO newname
| POSITION newpos
| <regular_col_mod>
| <computed_col_mod>
| <identity_col_mod>
<regular_col_mod> ::=
TYPE {<datatype> | domainname}
| SET DEFAULT {<literal> | NULL | <context_var>}
| DROP DEFAULT
| {SET | DROP} NOT NULL
<computed_col_mod> ::=
[TYPE <datatype>] {COMPUTED [BY] | GENERATED ALWAYS AS} (<expression>)
<identity_col_mod> ::=
SET GENERATED {ALWAYS | BY DEFAULT} [<identity_mod_option>...]
| <identity_mod_options>...
| DROP IDENTITY
<identity_mod_options> ::=
RESTART [WITH restart_value]
| SET INCREMENT [BY] inc_value
!! See CREATE TABLE
syntax for further rules !!
Parameter | Description |
---|---|
tablename |
Name (identifier) of the table |
operation |
One of the available operations altering the structure of the table |
colname |
Name (identifier) for a column in the table.The maximum length is 63 characters.Must be unique in the table. |
domain_name |
Domain name |
newname |
New name (identifier) for the column.The maximum length is 63 characters.Must be unique in the table. |
newpos |
The new column position (an integer between 1 and the number of columns in the table) |
other_table |
The name of the table referenced by the foreign key constraint |
literal |
A literal value that is allowed in the given context |
context_var |
A context variable whose type is allowed in the given context |
check_condition |
The condition of a |
restart_value |
The first value of the identity column after restart |
inc_value |
The increment (or step) value of the identity column;zero ( |
The ALTER TABLE
statement changes the structure of an existing table.With one ALTER TABLE
statement it is possible to perform multiple operations, adding/dropping columns and constraints and also altering column specifications.
Multiple operations in an ALTER TABLE
statement are separated with commas.
Some changes in the structure of a table increment the metadata change counter (“version count”) assigned to every table.The number of metadata changes is limited to 255 for each table, or 32,000 for each view.Once the counter reaches this limit, you will not be able to make any further changes to the structure of the table or view without resetting the counter.
SET NOT NULL
and DROP NOT NULL
ClausesThe SET NOT NULL
clause adds a NOT NULL
constraint on an existing table column.Contrary to definition in CREATE TABLE
, it is not possible to specify a constraint name.
Note
|
The successful addition of the An explicit |
Dropping the NOT NULL
constraint from the column if its type is a domain that also has a NOT NULL
constraint, has no observable effect until the NOT NULL
constraint is dropped from the domain as well.
COMPUTED [BY]
or GENERATED ALWAYS AS
ClausesThe data type and expression underlying a computed column can be modified using a COMPUTED [BY]
or GENERATED ALWAYS AS
clause in the ALTER TABLE ALTER [COLUMN]
statement.Conversion of a regular column to a computed one and vice versa is not permitted.
For identity columns (SET GENERATED {ALWAYS | BY DEFAULT}
) it is possible to modify several properties using the following clauses.
The SET GENERATED {ALWAYS | BY DEFAULT}
changes an identity column from ALWAYS
to BY DEFAULT
and vice versa.It is not possible to use this to change a regular column to an identity column.
RESTART
The RESTART
clause restarts the sequence used for generating identity values.If only the RESTART
clause is specified, then the sequence resets to the initial value specified when the identity column was defined.If the optional WITH restart_value
clause is specified, the sequence will restart with the specified value.
Note
|
In Firebird 3.0, It is currently not possible to change the configured start value. |
SET INCREMENT
The SET INCREMENT
clause changes the increment of the identity column.
DROP IDENTITY
The DROP IDENTITY
clause will change an identity column to a regular column.
Note
|
It is not possible to change a regular column to an identity column. |
Using the ALTER SQL SECURITY
or DROP SQL SECURITY
clauses, it is possible to change or drop the SQL Security property of a table.After dropping SQL Security, the default value of the database is applied at runtime.
Note
|
If the SQL Security property is changed for a table, triggers that do not have an explicit SQL Security property will not see the effect of the change until the next time the trigger is loaded into the metadata cache. |
To stop replicating a table, use the DISABLE PUBLICATION
clause.To start replicating a table, use the ENABLE PUBLICATION
clause.
The change in publication status takes effect at commit.
The following alterations are not supported:
Changing the collation of a character type column
The ALTER TABLE
statement can be executed by:
The owner of the table
Users with the ALTER ANY TABLE
privilege
ALTER TABLE
Adding the CAPITAL
column to the COUNTRY
table.
ALTER TABLE COUNTRY
ADD CAPITAL VARCHAR(25);
Adding the CAPITAL
column with the NOT NULL
and UNIQUE
constraint and deleting the CURRENCY
column.
ALTER TABLE COUNTRY
ADD CAPITAL VARCHAR(25) NOT NULL UNIQUE,
DROP CURRENCY;
Adding the CHK_SALARY
check constraint and a foreign key to the JOB
table.
ALTER TABLE JOB
ADD CONSTRAINT CHK_SALARY CHECK (MIN_SALARY < MAX_SALARY),
ADD FOREIGN KEY (JOB_COUNTRY) REFERENCES COUNTRY (COUNTRY);
Setting default value for the MODEL
field, changing the type of the ITEMID
column and renaming the MODELNAME column.
ALTER TABLE STOCK
ALTER COLUMN MODEL SET DEFAULT 1,
ALTER COLUMN ITEMID TYPE BIGINT,
ALTER COLUMN MODELNAME TO NAME;
Restarting the sequence of an identity column.
ALTER TABLE objects
ALTER ID RESTART WITH 100;
Changing the computed columns NEW_SALARY
and SALARY_CHANGE
.
ALTER TABLE SALARY_HISTORY
ALTER NEW_SALARY GENERATED ALWAYS AS
(OLD_SALARY + OLD_SALARY * PERCENT_CHANGE / 100),
ALTER SALARY_CHANGE COMPUTED BY
(OLD_SALARY * PERCENT_CHANGE / 100);
ADD
ClauseWith the ADD
clause you can add a new column or a new table constraint.The syntax for defining the column and the syntax of defining the table constraint correspond with those described for [fblangref50-ddl-tbl-create] statement.
Each time a new column is added, the metadata change counter is increased by one
Adding a new table constraint does not increase the metadata change counter
Caution
|
Points to Be Aware of
|
DROP
ClauseThe DROP colname
clause deletes the specified column from the table.An attempt to drop a column will fail if anything references it.Consider the following items as sources of potential dependencies:
column or table constraints
indexes
stored procedures, functions and triggers
views
Each time a column is dropped, the table’s metadata change counter is increased by one.
DROP CONSTRAINT
ClauseThe DROP CONSTRAINT
clause deletes the specified column-level or table-level constraint.
A PRIMARY KEY
or UNIQUE
key constraint cannot be deleted if it is referenced by a FOREIGN KEY
constraint in another table.It will be necessary to drop that FOREIGN KEY
constraint before attempting to drop the PRIMARY KEY
or UNIQUE
key constraint it references.
Deleting a column constraint or a table constraint does not increase the metadata change counter.
ALTER [COLUMN]
ClauseWith the ALTER [COLUMN]
clause, attributes of existing columns can be modified without the need to drop and re-add the column.Permitted modifications are:
change the name (does not affect the metadata change counter)
change the data type (increases the metadata change counter by one)
change the column position in the column list of the table (does not affect the metadata change counter)
delete the default column value (does not affect the metadata change counter)
set a default column value or change the existing default (does not affect the metadata change counter)
change the type and expression for a computed column (does not affect the metadata change counter)
set the NOT NULL
constraint (does not affect the metadata change counter)
drop the NOT NULL
constraint (does not affect the metadata change counter)
change the type of an identity column, or change an identity column to a regular column
restart an identity column
change the increment of an identity column
TO
ClauseThe TO
keyword with a new identifier renames an existing column.The table must not have an existing column that has the same identifier.
It will not be possible to change the name of a column that is included in any constraint: primary key, unique key, foreign key, or CHECK
constraints of the table.
Renaming a column will also be disallowed if the column is used in any stored PSQL module or view.
TYPE
ClauseThe keyword TYPE
changes the data type of an existing column to another, allowable type.A type change that might result in data loss will be disallowed.As an example, the number of characters in the new type for a CHAR
or VARCHAR
column cannot be smaller than the existing specification for it.
If the column was declared as an array, no change to its type or its number of dimensions is permitted.
The data type of a column that is involved in a foreign key, primary key or unique constraint cannot be changed at all.
POSITION
ClauseThe POSITION
keyword changes the position of an existing column in the notional “left-to-right” layout of the record.
Numbering of column positions starts at 1.
If a position less than 1 is specified, an error message will be returned
If a position number is greater than the number of columns in the table, its new position will be adjusted silently to match the number of columns.
DROP DEFAULT
and SET DEFAULT
ClausesThe optional DROP DEFAULT
clause deletes the current default value for the column.
If the column is based on a domain with a default value, the default value will revert to the domain default
An error will be raised if an attempt is made to delete the default value of a column which has no default value or whose default value is domain-based
The optional SET DEFAULT
clause sets a default value for the column.If the column already has a default value, it will be replaced with the new one.The default value applied to a column always overrides one inherited from a domain.
DROP TABLE
Drops a table
DSQL, ESQL
DROP TABLE tablename
Parameter | Description |
---|---|
tablename |
Name (identifier) of the table |
The DROP TABLE
statement drops (deletes) an existing table.If the table has dependencies, the DROP TABLE
statement will fail with an error.
When a table is dropped, all its triggers and indexes will be deleted as well.
The DROP TABLE
statement can be executed by:
The owner of the table
Users with the DROP ANY TABLE
privilege
DROP TABLE
COUNTRY
table.DROP TABLE COUNTRY;
RECREATE TABLE
Drops a table if it exists, and creates a table
DSQL
RECREATE [GLOBAL TEMPORARY] TABLE tablename [EXTERNAL [FILE] 'filespec'] (<col_def> [, {<col_def> | <tconstraint>} ...]) [{<table_attrs> | <gtt_table_attrs>}]
See the CREATE TABLE
section for the full syntax of CREATE TABLE
and descriptions of defining tables, columns and constraints.
RECREATE TABLE
creates or recreates a table.If a table with this name already exists, the RECREATE TABLE
statement will try to drop it and create a new one.Existing dependencies will prevent the statement from executing.
RECREATE TABLE
COUNTRY
table.RECREATE TABLE COUNTRY (
COUNTRY COUNTRYNAME NOT NULL PRIMARY KEY,
CURRENCY VARCHAR(10) NOT NULL
);