|
| 1 | += Identity Columns |
| 2 | +:database-version: 12.1.0.1 |
| 3 | +:database-category: sql |
| 4 | + |
| 5 | +The identity columns feature can be used to designate one column in the table as the identity for the row. |
| 6 | +The database will automatically assign an increasing integer value from a sequence generator to the identity column for each subsequent INSERT statement. |
| 7 | +This feature is sometimes also referred to as `autoincrement`. |
| 8 | + |
| 9 | +*This feature is part of the ISO SQL:2016 standard.* |
| 10 | + |
| 11 | +To declare a column as an identity in a table, use the `GENERATED AS IDENTITY` column attribute: |
| 12 | + |
| 13 | +[source,sql] |
| 14 | +[subs="verbatim"] |
| 15 | +---- |
| 16 | +CREATE TABLE employees |
| 17 | +( |
| 18 | + id NUMBER GENERATED AS IDENTITY NOT NULL PRIMARY KEY, |
| 19 | + first_name VARCHAR2(10), |
| 20 | + last_name VARCHAR2(10) NOT NULL, |
| 21 | + job_title VARCHAR2(20) NOT NULL |
| 22 | +); |
| 23 | +---- |
| 24 | + |
| 25 | +The identity column provides additional syntax modifiers to: |
| 26 | + |
| 27 | +* Always generate a new identity value, via `GENERATED ALWAYS AS IDENTITY` |
| 28 | +* Generate a new identity value if none has been provided, via `GENERATED BY DEFAULT` |
| 29 | +* Generate a new identity value if one has been provided by evaluates to `NULL`, via `GENERATED BY DEFAULT ON NULL` |
| 30 | +* Provide additional identity generation options via `GENERATED AS IDENTITY (<identity_options>)` |
| 31 | +
|
| 32 | +.Result |
| 33 | +[source,sql] |
| 34 | +[subs="verbatim"] |
| 35 | +---- |
| 36 | +SQL> CREATE TABLE employees |
| 37 | + 2 ( |
| 38 | + 3 id NUMBER GENERATED AS IDENTITY NOT NULL PRIMARY KEY, |
| 39 | + 4 first_name VARCHAR2(10), |
| 40 | + 5 last_name VARCHAR2(10) NOT NULL, |
| 41 | + 6 job_title VARCHAR2(20) NOT NULL |
| 42 | + 7 ); |
| 43 | +
|
| 44 | +Table EMPLOYEES created. |
| 45 | +
|
| 46 | +SQL> INSERT INTO employees (first_name, last_name, job_title) |
| 47 | + 2 VALUES ('Gerald', 'Venzl', 'Developer'); |
| 48 | +
|
| 49 | +1 row inserted. |
| 50 | +
|
| 51 | +SQL> INSERT INTO employees (first_name, last_name, job_title) |
| 52 | + 2 VALUES ('Andres', 'Almiray', 'Developer'); |
| 53 | +
|
| 54 | +1 row inserted. |
| 55 | +
|
| 56 | +SQL> INSERT INTO employees (first_name, last_name, job_title) |
| 57 | + 2 VALUES ('Chris', 'Saxon', 'Developer Evangelist'); |
| 58 | +
|
| 59 | +1 row inserted. |
| 60 | +
|
| 61 | +SQL> COMMIT; |
| 62 | +
|
| 63 | +Commit complete. |
| 64 | +
|
| 65 | +SQL> SELECT * FROM employees; |
| 66 | +
|
| 67 | +ID FIRST_NAME LAST_NAME JOB_TITLE |
| 68 | +-- ---------- --------- -------------------- |
| 69 | + 1 Gerald Venzl Developer |
| 70 | + 2 Andres Almiray Developer |
| 71 | + 3 Chris Saxon Developer Evangelist |
| 72 | +---- |
| 73 | + |
| 74 | +== Benefits |
| 75 | + |
| 76 | +The first relational normal form dictates that each table has to have a primary key by which a row can be uniquely identified (i.e. only one row exists for a given primary key value). |
| 77 | +Sometimes data records contain "natural primary keys" that uniquely identify themselves, such as the user name for a `customer_accounts` table, the VIN (Vehicle Identification Number) for a `cars` table, the driver license id for a `driver _licenses` table. |
| 78 | +However, often such natural primary keys do not exist within the data records and need to instead be generated, which is where identity columns can help. |
| 79 | + |
| 80 | +Identity columns ensure that the value for a new row will always be unique by using an always incrementing integer value that will never be used twice. |
| 81 | + |
| 82 | +== Further information |
| 83 | + |
| 84 | +* Introduced: xref:versions:{database-version}/index.adoc[] |
| 85 | +* Availability: all editions |
| 86 | +* link:https://docs.oracle.com/en/database/oracle/oracle-database/19/sqlrf/CREATE-TABLE.html#GUID-F9CE0CC3-13AE-4744-A43C-EAC7A71AAAB6__CJAECCFH[Documentation - CREATE TABLE identity_clause] |
| 87 | +* link:https://docs.oracle.com/en/database/oracle/oracle-database/19/sqlrf/CREATE-TABLE.html#GUID-F9CE0CC3-13AE-4744-A43C-EAC7A71AAAB6__CJAHCAFF[Example] |
0 commit comments