|
| 1 | +CREATE TABLE main_datatypes ( |
| 2 | + /* serials aka sequences */ |
| 3 | + id bigserial PRIMARY KEY, -- serial/bigserial corresponds to int4/int8 and will just auto-attach a DEFAULT sequence |
| 4 | + |
| 5 | + /* numbers */ |
| 6 | + smallish_integers int, -- int4 or integer, |
| 7 | + large_integers int8, -- for big-data i.e. > 2 billion rows |
| 8 | + floating_point double precision, -- for non-exact calculations. synonymous with "float8" |
| 9 | + exact_calculations numeric, -- for scientific/financial calculations. synonymous with "decimal" |
1 | 10 |
|
| 11 | + /* character data */ |
| 12 | + text_data1 text, -- for text data it's generally recommended to just use the "text" type |
| 13 | + text_data2 varchar(200), -- when limiting input needs to be enforced use varchar(X) |
| 14 | + text_fixed char(3), -- for fixed size data like currency codes |
| 15 | + json_data jsonb, -- efficiently stored and indexable JSON texts, meant for NoSQL use cases |
2 | 16 |
|
| 17 | + /* temporals */ |
| 18 | + event_ts timestamptz, -- timestamptz = "timestamp with time zone" and should always be used instead of simple "timestamp" |
| 19 | + event_date date, -- '2017-08-15' |
| 20 | + event_time time, -- '17:35' |
| 21 | + event_duration interval, -- '1day', '2years 1month', '3h 0m 10s' |
| 22 | + |
| 23 | + is_active boolean, -- boolean input can be specified as true/false (case insensitive), t/f, on/off |
| 24 | + |
| 25 | + /* typical auditing fields to track changes of important data*/ |
| 26 | + created_by text NOT NULL DEFAULT current_user, |
| 27 | + created_on timestamptz NOT NULL DEFAULT now(), |
| 28 | + last_modified_by text -- would need a trigger to ensure it's always updated when changing data |
| 29 | + last_modified_on timestamptz, -- would need a trigger to ensure it's always updated when changing data |
| 30 | +); |
3 | 31 |
|
4 | 32 |
|
5 | 33 |
|
6 | | -CREATE TABLE t_demo ( |
7 | | - id serial PRIMARY KEY, |
8 | | - data jsonb, |
9 | | - department text NOT NULL, |
10 | | - created_by text NOT NULL DEFAULT current_user, |
11 | | - created_on timestamptz NOT NULL DEFAULT now(), |
12 | | - last_modified_on timestamptz |
13 | | -); |
| 34 | +/* Numerals */ |
| 35 | + |
| 36 | +INSERT INTO main_datatypes(large_integers) |
| 37 | + SELECT 1e11; --100 billion |
| 38 | + |
| 39 | +INSERT INTO main_datatypes(floating_point) |
| 40 | + SELECT 3.14; |
| 41 | + |
| 42 | +/* character data */ |
| 43 | + |
| 44 | +INSERT INTO main_datatypes(text_data1) -- take only first 10 chars of 300 |
| 45 | + SELECT repeat('a', 300)::char(10); |
| 46 | + |
| 47 | +--INSERT INTO main_datatypes(text_data2) -- this will fail as text_data2 allows max 200 chars |
| 48 | +-- SELECT repeat('a', 300); |
| 49 | + |
| 50 | +INSERT INTO main_datatypes (json_data) |
| 51 | + VALUES ('{"user_id": 1, "order_items": [{"item_id":3, "code": "EAS123"}], "created_on": "2017-08-15 11:45:28.852685+03"}'); |
| 52 | + |
| 53 | + |
| 54 | + |
| 55 | +/* |
| 56 | +Temporals - postgres has excellent support for working with times. Here some most used functions. |
| 57 | + */ |
| 58 | + |
| 59 | +-- current timestamptz as of beginning of transaction, thus we'll see the same values |
| 60 | +BEGIN; |
| 61 | +SELECT now(); |
| 62 | +SELECT now(); |
| 63 | +END; |
| 64 | + |
| 65 | +-- same |
| 66 | +SELECT 'now'::timestamptz; |
| 67 | + |
| 68 | +-- current timestamptz in real time, different values |
| 69 | +BEGIN; |
| 70 | +SELECT clock_timestamp(); |
| 71 | +SELECT clock_timestamp(); |
| 72 | +END; |
14 | 73 |
|
15 | | -COMMENT ON TABLE t_demo IS 'a simple table'; |
16 | | -COMMENT ON COLUMN t_demo.data IS 'JSONB is designed for NoSQL'; |
| 74 | +-- current date |
| 75 | +SELECT 'today'::date; |
| 76 | +SELECT current_date; |
| 77 | +SELECT now()::date; |
17 | 78 |
|
18 | | -INSERT INTO t_demo (data, department) |
19 | | - VALUES ('{"user_id": 1, "order_items": [{"item_id":3, "code": "EAS123"}]}', 'sales'); |
| 79 | +-- using interval to get exact date of 90 days ago |
| 80 | +SELECT current_date - '90d'::interval; |
20 | 81 |
|
21 | | --- index top level keys for a simple NoSQL use case. |
22 | | -CREATE INDEX CONCURRENTLY ON t_demo USING gin (data); |
| 82 | +-- current UNIX epoch seconds |
| 83 | +SELECT extract(epoch FROM now()); |
23 | 84 |
|
24 | | --- index everything |
25 | | -CREATE INDEX ON t_demo USING gin (data jsonb_path_ops); |
| 85 | +-- generate all dates for the last week |
| 86 | +SELECT generate_series(date_trunc('week', now() - '1 week'::interval), |
| 87 | + date_trunc('week', now()) - '1day'::interval, '1day'); |
26 | 88 |
|
27 | | --- Prepare for frequent changes, increase FILLFACTOR |
28 | | -ALTER TABLE t_demo SET (fillfactor=80); |
| 89 | +-- same as above but with ORDINALITY |
| 90 | +SELECT |
| 91 | + * |
| 92 | +FROM generate_series(date_trunc('week', now() - '1 week'::interval), date_trunc('week', now()) - '1day'::interval, '1day') |
| 93 | + WITH ORDINALITY t(date, day_of_week); |
0 commit comments