DDL - Tables
CREATE TABLE
CREATE TABLE [IF NOT EXISTS] <table>
(<column> <type> [NOT NULL] [ENCODING <encodingSpec>],
[SHARD KEY (<column>)],
[SHARED DICTIONARY (<column>) REFERENCES <table>(<column>)], ...)
[WITH (<property> = value, ...)];
Create a table named <table>
specifying <columns>
and table properties.
<type>
Supported types:
Datatype | Size (bytes) | Notes |
---|---|---|
TEXT ENCODING DICT |
4 | Max cardinality 1 billion distinct string values |
TEXT ENCODING NONE |
Variable | Size of the string + 6 bytes |
TIMESTAMP |
8 | Linux timestamp from 30610224000000 (1/1/1000 00:00:00.000 ) through 29379542399999 (12/31/2900 23:59:59.999 ). Can also be inserted and stored in human-readable format (YYYY-MM-DD HH:MM:S ). |
TIME |
8 | Minimum value: 00:00:00 ; maximum value: 23:59:59 . |
DATE |
8 | Minimum value: 1000-01-01 ; maximum value: 2900-12-31 . |
FLOAT |
4 | Variable precision. Minimum value: -3.4 x e^38 ; maximum value: 3.4 x e^38 . |
DOUBLE |
8 | Variable precision. Minimum value: -1.79 x e^308 ; maximum value: 1.79 x e^308 . |
INTEGER |
4 | Minimum value: -2,147,483,647 ; maximum value: 2,147,483,647 . |
TINYINT |
1 | Minimum value: -127 ; maximum value: 127 . |
SMALLINT |
2 | Minimum value: -32,767 ; maximum value: 32,767 . |
BIGINT |
8 | Minimum value: -9,223,372,036,854,775,807 ; maximum value: 9,223,372,036,854,775,807 . |
BOOLEAN |
1 | TRUE: 'true' , '1' , 't' . FALSE: 'false' , '0' , 'f' . Text values are not case-sensitive. |
DECIMAL/NUMERIC |
8 | Precise. Maximum precision: 19 . Scale must be less than precision. |
For more information, see Datatypes and Fixed Encoding.
For geospatial datatypes, see Geospatial Primitives.
Example
Create a table named tweets
and specify the columns, including type, in the table.
CREATE TABLE IF NOT EXISTS tweets (
tweet_id BIGINT NOT NULL,
tweet_time TIMESTAMP NOT NULL ENCODING FIXED(32),
lat FLOAT,
lon FLOAT,
sender_id BIGINT NOT NULL,
sender_name TEXT NOT NULL ENCODING DICT,
location TEXT ENCODING DICT,
source TEXT ENCODING DICT,
reply_to_user_id BIGINT,
reply_to_tweet_id BIGINT,
lang TEXT ENCODING DICT,
followers INT,
followees INT,
tweet_count INT,
join_time TIMESTAMP ENCODING FIXED(32),
tweet_text TEXT,
state TEXT ENCODING DICT,
county TEXT ENCODING DICT,
place_name TEXT,
state_abbr TEXT ENCODING DICT,
county_state TEXT ENCODING DICT,
origin TEXT ENCODING DICT,
phone_numbers bigint);