5.3. DOMAIN
DOMAIN
is one of the object types in a relational database.
A domain is created as a specific data type with some attributes attached to it.
Once it has been defined in the database, it can be reused repeatedly to define table columns, PSQL arguments and PSQL local variables.
Those objects inherit all of the attributes of the domain.
Some attributes can be overridden when the new object is defined, if required.
This section describes the syntax of statements used to create, modify and delete domains. A detailed description of domains and their usage can be found in Custom Data Types — Domains.
5.3.1. CREATE DOMAIN
Used forCreating a new domain
Available inDSQL, ESQL
Syntax
|
CREATE DOMAIN name [AS] <datatype>
| [DEFAULT {<literal> | NULL | <context_var>}]
| [NOT NULL] [CHECK (<dom_condition>)]
| [COLLATE collation_name]
|
|<datatype> ::=
| <scalar_datatype> | <blob_datatype> | <array_datatype>
|
|<scalar_datatype> ::=
| !! See Scalar Data Types Syntax !!
|
|<blob_datatype> ::=
| !! See BLOB Data Types Syntax !!
|
|<array_datatype> ::=
| !! See Array Data Types Syntax !!
|
|<dom_condition> ::=
| <val> <operator> <val>
| | <val> [NOT] BETWEEN <val> AND <val>
| | <val> [NOT] IN ({<val> [, <val> ...] | <select_list>})
| | <val> IS [NOT] NULL
| | <val> IS [NOT] DISTINCT FROM <val>
| | <val> [NOT] CONTAINING <val>
| | <val> [NOT] STARTING [WITH] <val>
| | <val> [NOT] LIKE <val> [ESCAPE <val>]
| | <val> [NOT] SIMILAR TO <val> [ESCAPE <val>]
| | <val> <operator> {ALL | SOME | ANY} (<select_list>)
| | [NOT] EXISTS (<select_expr>)
| | [NOT] SINGULAR (<select_expr>)
| | (<dom_condition>)
| | NOT <dom_condition>
| | <dom_condition> OR <dom_condition>
| | <dom_condition> AND <dom_condition>
|
|<operator> ::=
| <> | != | ^= | ~= | = | < | > | <= | >=
| | !< | ^< | ~< | !> | ^> | ~>
|
|<val> ::=
| VALUE
| | <literal>
| | <context_var>
| | <expression>
| | NULL
| | NEXT VALUE FOR genname
| | GEN_ID(genname, <val>)
| | CAST(<val> AS <cast_type>)
| | (<select_one>)
| | func([<val> [, <val> ...]])
|
|<cast_type> ::= <domain_or_non_array_type> | <array_datatype>
|
|<domain_or_non_array_type> ::=
| !! See Scalar Data Types Syntax !!
CREATE DOMAIN
Statement ParametersParameter | Description |
---|---|
name | Domain name consisting of up to 31 characters |
datatype | SQL data type |
literal | A literal value that is compatible with datatype |
context_var | Any context variable whose type is compatible with datatype |
dom_condition | Domain condition |
collation_name | Name of a collation sequence that is valid for charset_name, if it is supplied with datatype or, otherwise, is valid for the default character set of the database |
select_one | A scalar |
select_list | A |
select_expr | A |
expression | An expression resolving to a value that is compatible with datatype |
genname | Sequence (generator) name |
func | Internal function or UDF |
The CREATE DOMAIN
statement creates a new domain.
Any SQL data type can be specified as the domain type.
5.3.1.1. Type-specific Details
- Array Types
If the domain 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. (In the Syntax block, these brackets appear in quotes to distinguish them from the square brackets that identify optional syntax elements.)
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
.
- String Types
You can use the
CHARACTER SET
clause to specify the character set for theCHAR
,VARCHAR
andBLOB
(SUB_TYPE TEXT
) types. If the character set is not specified, the character set specified asDEFAULT CHARACTER SET
of the database will be used. If no character set was specified then, the character setNONE
is applied by default when you create a character domain.🛑WarningWith character set
NONE
, character data are stored and retrieved the way they were submitted. Data in any encoding can be added to a column based on such a domain, but it is impossible to add this data to a column with a different encoding. Because no transliteration is performed between the source and destination encodings, errors may result.DEFAULT
ClauseThe optional
DEFAULT
clause allows you to specify a default value for the domain. This value will be added to the table column that inherits this domain when theINSERT
statement is executed, if no value is specified for it in the DML statement. Local variables and arguments in PSQL modules that reference this domain will be initialized with the default value. For the default value, use a literal of a compatible type or a context variable of a compatible type.NOT NULL
ConstraintColumns and variables based on a domain with the
NOT NULL
constraint will be prevented from being written asNULL
, i.e., a value is required.⚠CautionWhen creating a domain, take care to avoid specifying limitations that would contradict one another. For instance,
NOT NULL
andDEFAULT NULL
are contradictory.CHECK
Constraint(s)The optional
CHECK
clause specifies constraints for the domain. A domain constraint specifies conditions that must be satisfied by the values of table columns or variables that inherit from the domain. A condition must be enclosed in parentheses. A condition is a logical expression (also called a predicate) that can return the Boolean resultsTRUE
,FALSE
andUNKNOWN
. A condition is considered satisfied if the predicate returns the valueTRUE
orunknown value
(equivalent toNULL
). If the predicate returnsFALSE
, the condition for acceptance is not met.VALUE
KeywordThe keyword
VALUE
in a domain constraint substitutes for the table column that is based on this domain or for a variable in a PSQL module. It contains the value assigned to the variable or the table column.VALUE
can be used anywhere in theCHECK
constraint, though it is usually used in the left part of the condition.COLLATE
The optional
COLLATE
clause allows you to specify the collation sequence if the domain is based on one of the string data types, includingBLOB
s with text subtypes. If no collation sequence is specified, the collation sequence will be the one that is default for the specified character set at the time the domain is created.
5.3.1.2. Who Can Create a Domain
The CREATE DOMAIN
statement can be executed by:
Users with the
CREATE DOMAIN
privilege
5.3.1.3. CREATE DOMAIN
Examples
Creating a domain that can take values greater than 1,000, with a default value of 10,000.
|
CREATE DOMAIN CUSTNO AS
|INTEGER DEFAULT 10000
|CHECK (VALUE > 1000);
Creating a domain that can take the values 'Yes' and 'No' in the default character set specified during the creation of the database.
|
CREATE DOMAIN D_BOOLEAN AS
|CHAR(3) CHECK (VALUE IN ('Yes', 'No'));
Creating a domain with the
UTF8
character set and theUNICODE_CI_AI
collation sequence.|
CREATE DOMAIN FIRSTNAME AS
|VARCHAR(30) CHARACTER SET UTF8
|COLLATE UNICODE_CI_AI;
Creating a domain of the
DATE
type that will not accept NULL and uses the current date as the default value.|
CREATE DOMAIN D_DATE AS
|DATE DEFAULT CURRENT_DATE
|NOT NULL;
Creating a domain defined as an array of 2 elements of the
NUMERIC(18, 3)
type. The starting array index is 1.|
CREATE DOMAIN D_POINT AS
|NUMERIC(18, 3) [2];
ⓘNoteDomains defined over an array type may be used only to define table columns. You cannot use array domains to define local variables in PSQL modules.
Creating a domain whose elements can be only country codes defined in the
COUNTRY
table.|
CREATE DOMAIN D_COUNTRYCODE AS CHAR(3)
|CHECK (EXISTS(SELECT * FROM COUNTRY
|WHERE COUNTRYCODE = VALUE));
ⓘNoteThe example is given only to show the possibility of using predicates with queries in the domain test condition. It is not recommended to create this style of domain in practice unless the lookup table contains data that are never deleted.
See alsoSection 5.3.2, “ALTER DOMAIN
”, Section 5.3.3, “DROP DOMAIN
”
5.3.2. ALTER DOMAIN
Used forAltering the current attributes of a domain or renaming it
Available inDSQL, ESQL
Syntax
|
ALTER DOMAIN domain_name
| [TO new_name]
| [TYPE <datatype>]
| [{SET DEFAULT {<literal> | NULL | <context_var>} | DROP DEFAULT}]
| [{SET | DROP} NOT NULL]
| [{ADD [CONSTRAINT] CHECK (<dom_condition>) | DROP CONSTRAINT}]
|
|<datatype> ::=
| <scalar_datatype> | <blob_datatype>
|
|<scalar_datatype> ::=
| !! See Scalar Data Types Syntax !!
|
|<blob_datatype> ::=
| !! See BLOB Data Types Syntax !!
|
|!! See also
CREATE DOMAIN
Syntax !!
ALTER DOMAIN
Statement ParametersParameter | Description |
---|---|
new_name | New name for domain, consisting of up to 31 characters |
literal | A literal value that is compatible with datatype |
context_var | Any context variable whose type is compatible with datatype |
The ALTER DOMAIN
statement enables changes to the current attributes of a domain, including its name.
You can make any number of domain alterations in one ALTER DOMAIN
statement.
5.3.2.1. ALTER DOMAIN
clauses
TO name
Use the
TO
clause to rename the domain, as long as there are no dependencies on the domain, i.e. table columns, local variables or procedure arguments referencing it.SET DEFAULT
With the
SET DEFAULT
clause you can set a new default value. If the domain already has a default value, there is no need to delete it first — it will be replaced by the new one.DROP DEFAULT
Use this clause to delete a previously specified default value and replace it with
NULL
.SET NOT NULL
Use this class to add a
NOT NULL
constraint to the domain; columns or parameters of this domain will be prevented from being written asNULL
, i.e., a value is required.ⓘNoteAdding a
NOT NULL
constraint to an existing domain will subject all columns using this comain to a full data validation, so ensure that the columns have no nulls before attempting the change.DROP NOT NULL
Drop the
NOT NULL
constraint from the domain.ⓘNoteAn explicit
NOT NULL
constraint on a column that depends on a domain prevails over the domain. In this situation, the modification of the domain to make it nullable does not propagate to the column.ADD CONSTRAINT CHECK
Use the
ADD CONSTRAINT CHECK
clause to add aCHECK
constraint to the domain. If the domain already has aCHECK
constraint, it will have to be deleted first, using anALTER DOMAIN
statement that includes aDROP CONSTRAINT
clause.TYPE
The
TYPE
clause is used to change the data type of the domain to a different, compatible one. The system will forbid any change to the type that could result in data loss. An example would be if the number of characters in the new type were smaller than in the existing type.
When you alter the attributes of a domain, existing PSQL code may become invalid. For information on how to detect it, read the piece entitled The RDB$VALID_BLR Field in Appendix A.
5.3.2.2. What ALTER DOMAIN
Cannot Alter
If the domain was declared as an array, it is not possible to change its type or its dimensions; nor can any other type be changed to an array type.
There is no way to change the default collation without dropping the domain and recreating it with the desired attributes.
5.3.2.3. Who Can Alter a Domain
The ALTER DOMAIN
statement can be executed by:
The owner of the domain
Users with the
ALTER ANY DOMAIN
privilege
Domain alterations can be prevented by dependencies from objects to which the user does not have sufficient privileges.
5.3.2.4. ALTER DOMAIN
Examples
Changing the data type to
INTEGER
and setting or changing the default value to 2,000:|
ALTER DOMAIN CUSTNO
|TYPE INTEGER
|SET DEFAULT 2000;
Renaming a domain.
|
ALTER DOMAIN D_BOOLEAN TO D_BOOL;
Deleting the default value and adding a constraint for the domain:
|
ALTER DOMAIN D_DATE
|DROP DEFAULT
|ADD CONSTRAINT CHECK (VALUE >= date '01.01.2000');
Changing the
CHECK
constraint:|
ALTER DOMAIN D_DATE
|DROP CONSTRAINT;
|ALTER DOMAIN D_DATE
|ADD CONSTRAINT CHECK
|(VALUE BETWEEN date '01.01.1900' AND date '31.12.2100');
Changing the data type to increase the permitted number of characters:
|
ALTER DOMAIN FIRSTNAME
|TYPE VARCHAR(50) CHARACTER SET UTF8;
Adding a
NOT NULL
constraint:|
ALTER DOMAIN FIRSTNAME
|SET NOT NULL;
Removing a
NOT NULL
constraint:|
ALTER DOMAIN FIRSTNAME
|DROP NOT NULL;
See alsoSection 5.3.1, “CREATE DOMAIN
”, Section 5.3.3, “DROP DOMAIN
”
5.3.3. DROP DOMAIN
Used forDeleting an existing domain
Available inDSQL, ESQL
Syntax
|
DROP DOMAIN domain_name
The DROP DOMAIN
statement deletes a domain that exists in the database.
It is not possible to delete a domain if it is referenced by any database table columns or used in any PSQL module.
In order to delete a domain that is in use, all columns in all tables that refer to the domain will have to be dropped and all references to the domain will have to be removed from PSQL modules.
5.3.3.1. Who Can Drop a Domain
The DROP DOMAIN
statement can be executed by:
The owner of the domain
Users with the
DROP ANY DOMAIN
privilege
5.3.3.2. Example of DROP DOMAIN
Deleting the COUNTRYNAME domain
|
DROP DOMAIN COUNTRYNAME;
See alsoSection 5.3.1, “CREATE DOMAIN
”, Section 5.3.2, “ALTER DOMAIN
”