A column definition (column_definition) can contain both column_name and data types.
The following data types can be distinguished:
·
Non-NULL value
Character
String, LONG Column, Number, Date Value,
Time
Value, Time Stamp Value,
BOOLEAN
Non-NULL values can be specified using the syntax element data_type .
<data_type> ::=
CHAR[ACTER]
[(<unsigned_integer>)]
[ASCII | BYTE
| UNICODE]
| VARCHAR
[(<unsigned_integer>)] [ASCII | BYTE | UNICODE]
| LONG
[VARCHAR] [ASCII | BYTE | UNICODE]
| BOOLEAN
| FIXED
(<unsigned_integer> [,<unsigned_integer>])
| FLOAT
(<unsigned_integer>)
| INT[EGER] | SMALLINT
| DATE |
TIME | TIMESTAMP
A code attribute can also be specified for the following character strings (ASCII, BYTE, or UNICODE) as part of a column_definition if necessary: CHAR[ACTER], VARCHAR, LONG[VARCHAR]
SQL Tutorial, Tables, Number Generator for a Single Column of a Table
In addition to the data types defined above, the following data types are also permitted in a column definition. The table below also indicates the way these are mapped to the above-mentioned data types.
Data Type |
Is Mapped To |
BINARY(p) |
FIXED(p) |
DEC[IMAL](p,s) |
FIXED(p,s) |
DEC[IMAL](p) |
FIXED(p) |
DEC[IMAL] |
FIXED(5) |
DOUBLE PRECISION |
FLOAT(38) |
FLOAT |
FLOAT(16) |
FLOAT(39..64) |
FLOAT(38) |
LONG VARCHAR |
LONG |
NUMERIC(p,s) |
FIXED(p,s) |
NUMERIC(p) |
FIXED(p) |
NUMERIC |
FIXED(5) |
REAL(p) |
FLOAT(p) |
REAL |
FLOAT(16) |
SERIAL |
FIXED(10) DEFAULT SERIAL |
SERIAL(p) |
FIXED(10) DEFAULT SERIAL(p) |
Note that, in the column definition (column_definition), the memory requirement of a column value depends on the data type. You can get a rough idea of the memory requirement using the following table. Please note that these values are intended as guidance values and are applicable in most cases but may vary depending on your system configuration.
Data Type |
Memory Requirements of a Column Value in Bytes for Data Type |
FIXED(p,s) |
(p+1) DIV 2 + 2 |
FLOAT(p) |
(p+1) DIV 2 + 2 |
BOOLEAN |
2 |
DATE |
9 |
TIME |
9 |
TIMESTAMP |
21 |
LONG |
9 |
CHAR(n); n<=30 |
n+1 |
CHAR(n); 30<n<=1023; key column |
n+1 |
CHAR(n); 30<n<=254; no key column |
n+2 |
CHAR(n); 254<n; no key column |
n+3 |
CHAR(n) UNICODE; n<=15 |
2*n+1 |
CHAR(n) UNICODE; 15<n<=511; key column |
2*n+1 |
CHAR(n) UNICODE; 15<n<=127; no key column |
2*n+2 |
CHAR(n) UNICODE; 127<n; no key column |
2*n+3 |
VARCHAR(n); n<=1023; key column |
n+1 |
VARCHAR(n); n<=254; no key column |
n+2 |
VARCHAR(n); 254<n; no key column |
n+3 |
VARCHAR(n) UNICODE; n<=511; key column |
2*n+1 |
VARCHAR(n) UNICODE; n<=127; no key column |
2*n+2 |
VARCHAR(n) UNICODE; 127<n; no key column |
2*n+3 |