Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

SERIAL type #362

Merged
merged 4 commits into from
Jun 9, 2016
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
5 changes: 3 additions & 2 deletions data-types.md
Original file line number Diff line number Diff line change
Expand Up @@ -7,11 +7,12 @@ CockroachDB supports the following data types. Click a type for more details.

Type | Description | Example
-----|-------------|--------
[`INT`](int.html) | 64-bit signed integer. | `12345`
[`INT`](int.html) | A 64-bit signed integer. | `12345`
[`SERIAL`](serial.html) | A unique 64-bit signed integer. | `148591304110702593 `
[`DECIMAL`](decimal.html) | An exact, fixed-point number. | `1.2345`
[`FLOAT`](float.html) | A 64-bit, inexact, floating-point number. | `1.2345`
[`BOOL`](bool.html) | A Boolean value. | `true`
[`DATE`](date.html) | Year, month, day. | `DATE '2016-01-25'`
[`DATE`](date.html) | A date. | `DATE '2016-01-25'`
[`TIMESTAMP`](timestamp.html) | A date and time pairing. | `TIMESTAMP '2016-01-25 10:10:10'`
[`INTERVAL`](interval.html) | A span of time. | `INTERVAL '2h30m30s'`
[`STRING`](string.html) | A string of characters. | `'a1b2c3'`
Expand Down
2 changes: 2 additions & 0 deletions int.md
Original file line number Diff line number Diff line change
Expand Up @@ -5,6 +5,8 @@ toc: false

The `INT` [data type](data-types.html) stores 64-bit signed integers, that is, whole numbers from -9,223,372,036,854,775,808 to 9,223,372,036,854,775,807.

{{site.data.alerts.callout_info}}To auto-generate globally unique integers, use the <a href="serial.html"><code>SERIAL</code></a> data type.{{site.data.alerts.end}}

<div id="toc"></div>

## Aliases
Expand Down
101 changes: 101 additions & 0 deletions serial.md
Original file line number Diff line number Diff line change
@@ -0,0 +1,101 @@
---
title: SERIAL
toc: false
---

The `SERIAL` [data type](data-types.html) defaults to a unique 64-bit signed integer. The default value is the combination of the insert timestamp and the ID of the node executing the insert. This combination is guaranteed to be globally unique. Also, because value generation does not require talking to other nodes, it is much faster than sequentially auto-incrementing a value, which requires distributed coordination.

{{site.data.alerts.callout_info}}This data type is <strong>experimental</strong>. We believe it is a better solution than PostgeSQL's <code>SERIAL</code> and MySQL's <code>AUTO_INCREMENT</code> types, both of which auto-increment integers but not necessarily in a strictly sequential fashion (see the <a href="#auto-incrementing-is-not-always-sequential">Auto-Incrementing Is Not Always Sequential</a> example below). However, if you find that this feature is incompatible with your application, please <a href="https://github.com/cockroachdb/cockroach/issues">open an issue</a> or <a href="https://gitter.im/cockroachdb/cockroach">chat with us on Gitter</a>.{{site.data.alerts.end}}

<div id="toc"></div>

## Aliases

The `SERIAL` type is an alias for [`INT DEFAULT unique_rowid()`](int.html).

## Format

The `SERIAL` type is generally used to default to a unique ID. When inserting into a `SERIAL` column, you therefore do not manually specify a value.

## Size

A `SERIAL` column supports values up to 8 bytes in width, but the total storage size is likely to be larger due to CockroachDB metadata.

## Examples

### Use `SERIAL` to Auto-Generate Primary Keys

In this example, we create a table with the `SERIAL` column as the `PRIMARY KEY` so we can auto-generate unique IDs on insert.

~~~
> CREATE TABLE serial (a SERIAL PRIMARY KEY, b STRING(30), c BOOL);
CREATE TABLE
~~~

The [`SHOW COLUMNS`](show-columns.html) statement shows that the `SERIAL` type is just an alias for `INT` with `unique_rowid()` as the default.

~~~
> SHOW COLUMNS FROM serial;
+-------+------------+-------+----------------+
| Field | Type | Null | Default |
+-------+------------+-------+----------------+
| a | INT | false | unique_rowid() |
| b | STRING(30) | true | NULL |
| c | BOOL | true | NULL |
+-------+------------+-------+----------------+
~~~

When we insert 3 rows without values in column `a` and return the new rows, we see that each row has defaulted to a unique value in column `a`.

~~~
> INSERT INTO serial (b,c) VALUES ('red', true), ('yellow', false), ('pink', true) RETURNING *;
+--------------------+--------+-------+
| a | b | c |
+--------------------+--------+-------+
| 148656994422095873 | red | true |
| 148656994422161409 | yellow | false |
| 148656994422194177 | pink | true |
+--------------------+--------+-------+
~~~

### Auto-Incrementing Is Not Always Sequential

It's a common misconception that the auto-incrementing types in PostgreSQL and MySQL generate strictly sequential values. In fact, each insert increases the sequence by one, even when the insert is not commited. This means that auto-incrementing types may leave gaps in a sequence.

To experience this for yourself, run through the following example in PostgreSQL:

1. Create a table with a `SERIAL` column.

~~~
CREATE TABLE increment (a SERIAL PRIMARY KEY);
~~~

2. Run four transactions for inserting rows.

~~~
BEGIN; INSERT INTO increment DEFAULT VALUES; ROLLBACK;
BEGIN; INSERT INTO increment DEFAULT VALUES; COMMIT;
BEGIN; INSERT INTO increment DEFAULT VALUES; ROLLBACK;
BEGIN; INSERT INTO increment DEFAULT VALUES; COMMIT;
~~~

3. View the rows created.

~~~
SELECT * from increment;
+---+
| a |
+---+
| 2 |
| 4 |
+---+
~~~

Since each insert increased the sequence in column `a` by one, the first commited insert got the value `2`, and the second commited insert got the value `4`. As you can see, the values aren't strictly sequential, and the last value doesn't give an accurate count of rows in the table.

In summary, the `SERIAL` type in PostgreSQL and CockroachDB, and the `AUTO_INCREMENT` type in MySQL, all behave the same in that they do not create strict sequences. CockroachDB will likely create more gaps than these other databases, but will generate these values much faster.


## See Also

[Data Types](data-types.html)