From a0bf5c4aab743854de5d4603b738beb7a4edddef Mon Sep 17 00:00:00 2001 From: Michele Cereda Date: Mon, 7 Oct 2024 22:42:12 +0200 Subject: [PATCH] chore(postgres): dump learned queries and concepts --- knowledge base/mysql.md | 15 ++++- knowledge base/postgresql.md | 6 ++ knowledge base/sql.md | 43 +++++++++++++ snippets/postgres/commands.sh | 1 + snippets/postgres/primer.sql | 117 ++++++++++++++++++++++++++++------ snippets/pulumi/commands.fish | 5 ++ 6 files changed, 166 insertions(+), 21 deletions(-) create mode 100644 knowledge base/sql.md diff --git a/knowledge base/mysql.md b/knowledge base/mysql.md index ed39e45..5ffc037 100644 --- a/knowledge base/mysql.md +++ b/knowledge base/mysql.md @@ -1,9 +1,8 @@ # MySQL -## Table of contents - 1. [TL;DR](#tldr) 1. [Further readings](#further-readings) + 1. [Sources](#sources) ## TL;DR @@ -37,14 +36,24 @@ grant ALL on db.* to 'username'@'127.0.0.1'; ## Further readings +- [SQL] +- [PostgreSQL] + +### Sources + - How to [list tables] in MySQL - How to [show databases] in MySQL - [phpimap issue 1549] + +[postgresql]: postgresql.md +[sql]: sql.md + [list tables]: https://alvinalexander.com/blog/post/mysql/list-tables-in-mysql-database/ [show databases]: https://linuxize.com/post/how-to-show-databases-in-mysql/ diff --git a/knowledge base/postgresql.md b/knowledge base/postgresql.md index c281639..3b9623f 100644 --- a/knowledge base/postgresql.md +++ b/knowledge base/postgresql.md @@ -211,6 +211,7 @@ psql -h 'localhost' -p '6543' -U 'postgres' -d 'postgres' -W ## Further readings +- [SQL] - [Docker image] - [Bidirectional replication in PostgreSQL using pglogical] - [What is the pg_dump command for backing up a PostgreSQL database?] @@ -218,6 +219,7 @@ psql -h 'localhost' -p '6543' -U 'postgres' -d 'postgres' -W - [`postgresql_anonymizer`][postgresql_anonymizer] - [pgxn-manager] - [dverite/postgresql-functions] +- [MySQL] ### Sources @@ -238,6 +240,10 @@ psql -h 'localhost' -p '6543' -U 'postgres' -d 'postgres' -W ═╬═Time══ --> + +[mysql]: mysql.md +[sql]: sql.md + [docker image]: https://github.com/docker-library/docs/blob/master/postgres/README.md [psql]: https://www.postgresql.org/docs/current/app-psql.html diff --git a/knowledge base/sql.md b/knowledge base/sql.md new file mode 100644 index 0000000..739abe2 --- /dev/null +++ b/knowledge base/sql.md @@ -0,0 +1,43 @@ +# Structured Query Language + +Standard language for relational database management systems. + +## TL;DR + +`NULL` represents **unknown** or **missing** information.
+It is **not** the same as an empty string or the number 0. + +| Constraint | Description | +| ---------- | ---------------------------------------------- | +| `NOT NULL` | The value cannot be `NULL` | +| `UNIQUE` | The value must be unique in the table's column | + +_Primary keys_ are one or more columns in a table used to uniquely identify a single row.
+Tables can have **zero or one** primary keys. They **cannot** have more than one primary key. + +Technically, primary key constraints are the combination of a `NOT NULL` constraint and a `UNIQUE` constraint. + +_Foreign keys_ are one or more columns in a table that uniquely identify a row in **another** table.
+They reference either the primary key or another `UNIQUE` constraint of the referenced table. + +## Further readings + +- [The SQL Standard - ISO/IEC 9075:2023 (ANSI X3.135)] +- [PostgreSQL] +- [MySQL] + + + + + +[mysql]: mysql.md +[postgresql]: postgresql.md + + + +[the sql standard - iso/iec 9075:2023 (ansi x3.135)]: https://blog.ansi.org/sql-standard-iso-iec-9075-2023-ansi-x3-135/ + + diff --git a/snippets/postgres/commands.sh b/snippets/postgres/commands.sh index 6677766..05bb625 100644 --- a/snippets/postgres/commands.sh +++ b/snippets/postgres/commands.sh @@ -2,6 +2,7 @@ # Start DBs docker run --rm --name 'postgres' -d -p '5432:5432' -e POSTGRES_PASSWORD='password' 'postgres:14.12' +docker run --rm --name 'postgis' -d -p '5432:5432' -e POSTGRES_PASSWORD='password' 'postgis/postgis:14-3.4' # Start PgAdmin # Retain data in a volume between sessions diff --git a/snippets/postgres/primer.sql b/snippets/postgres/primer.sql index c948332..9ba1be9 100644 --- a/snippets/postgres/primer.sql +++ b/snippets/postgres/primer.sql @@ -259,28 +259,23 @@ SELECT * FROM users WHERE username IN ('matthew', 'lucas', 'todd', 'roxy', 'kyle SELECT * FROM users WHERE username NOT IN ('knives', 'wallace'); --- Shuffle data +-- Shuffle columns +-- needs some identifier for the join and where clauses - either use primary key or ctid -- source: https://stackoverflow.com/questions/33555524/postgresql-shuffle-column-values#33555639 WITH - ids AS ( - SELECT - row_number() OVER (ORDER BY random()) row_num, - vendor_id AS new_vendor_id - FROM vendors - ), - names AS ( - SELECT - row_number() OVER (ORDER BY random()) row_num, - vendor_name AS new_vendor_name - FROM vendors - ) + ids AS ( SELECT row_number() OVER (ORDER BY random()) row_num, vendor_id AS new_vendor_id FROM vendors ), + names AS ( SELECT row_number() OVER (ORDER BY random()) row_num, vendor_name AS new_vendor_name FROM vendors ) UPDATE vendors - SET - vendor_id = new_vendor_id, - vendor_name = new_vendor_name - FROM ids JOIN names ON ids.row_num = names.row_num + SET vendor_id = new_vendor_id, vendor_name = new_vendor_name FROM ids JOIN names ON ids.row_num = names.row_num WHERE vendor_id = new_vendor_id; - +-- +WITH + __ctids_in_order AS ( SELECT ROW_NUMBER() OVER (), ctid FROM vendors ), + __shuffled_names AS ( SELECT ROW_NUMBER() OVER (ORDER BY RANDOM()), vendor_name AS new_vendor_name FROM vendors ) +UPDATE vendors + SET vendor_name = __shuffled_names.new_vendor_name + FROM __shuffled_names JOIN __ctids_in_order ON __shuffled_names.row_number = __ctids_in_order.row_number + WHERE vendors.ctid = __ctids_in_order.ctid -- Deterministic random values SELECT setseed(0.25), round(random()::DECIMAL, 15) AS random_number; -- seed must be in [-1:1] @@ -312,6 +307,92 @@ SELECT CAST ('15 minute' AS INTERVAL), '3 month' :: INTERVAL, CAST ('20 days' AS TEXT), '24 hour':: TEXT, CAST (ARRAY[1,3,5] AS TEXT), + CAST (B'1001' AS INTEGER), x'123abc'::int, '{1,2,3}'::INTEGER[] AS result_array; SELECT to_char(42, '0000'); -- '0042' SELECT to_number('12,454.9', '99G999D9S'); + + +-- Atomic actions +BEGIN; + -- add ON UPDATE CASCADE to the 'signups_customer_id_fkey' constraint + -- ALTER TABLE 'x' ALTER CONSTRAINT does not support this action at the time of writing + ALTER TABLE signups RENAME CONSTRAINT signups_customer_id_fkey TO delete_me; + ALTER TABLE signups ADD CONSTRAINT signups_customer_id_fkey FOREIGN KEY (customer_id) REFERENCES customers(id) ON UPDATE CASCADE; + ALTER TABLE signups DROP CONSTRAINT delete_me; +COMMIT; +BEGIN; + ALTER TABLE customers RENAME COLUMN phone TO phone_old; + ALTER TABLE customers ADD COLUMN phone text UNIQUE; +COMMIT; + + +-- Timezones +SELECT * FROM pg_timezone_names; +-- Time functions +SELECT + NOW(), CURRENT_TIME, CURRENT_TIMESTAMP, -- current date and time *with* the time zone of the server + NOW()::timestamp, LOCALTIME, LOCALTIMESTAMP, -- current date and time *without* time zone + TIMEOFDAY(); + + +-- Search +SELECT table_schema, table_name, column_name +FROM information_schema.columns +WHERE column_name LIKE '%national_id%'; + + +-- Loops +DO $$ + DECLARE hashed_i TEXT; + BEGIN + FOR i IN 1..150000 + LOOP + hashed_i = LPAD(ABS(SUBSTRING(DIGEST(i::TEXT, 'sha1')::TEXT, 2, 8)::BIT(32)::INT/2.147483647)::INT::TEXT, 8, '0'); + IF hashed_i LIKE '00%' THEN + RAISE NOTICE '%: %', i, hashed_i; + END IF; + END LOOP; + END; +$$; +DO $$ + DECLARE column_info RECORD; -- required to use select in for definition + BEGIN + FOR column_info IN + SELECT table_schema AS schema, table_name AS table, column_name AS column + FROM information_schema.columns + WHERE column_name LIKE '%sensitive%' + LOOP + RAISE NOTICE 'target: %.%.%', column_info.schema, column_info.table, column_info.column; + PERFORM hash_data(column_info.table, column_info.column, column_info.schema); + END LOOP; + END; +$$; + + +-- Strings +-- escape single quotes by doubling them (' -> '') +query = 'SELECT table_schema AS schema, table_name AS table, column_name AS column FROM information_schema.columns WHERE column_name LIKE ''%national_id%'''; +SELECT ENCODE('something'::BYTEA, 'base64'); +SELECT CONVERT_FROM(DECODE('c29tZXRoaW5n', 'base64'), 'UTF-8'); + + +ALTER TABLE customers RENAME COLUMN phone TO phone_numbers; +ALTER TABLE signups RENAME CONSTRAINT signups_customer_id_fkey TO something_blue; +ALTER TABLE vendors SET CONSTRAINT vendors_value_uindex DEFERRED; + + +-- Show all constraints +SELECT + ns.nspname AS schema, + class.relname AS "table", + con.conname AS "constraint", + con.condeferrable AS "deferrable", + con.condeferred AS "deferred" +FROM pg_constraint con + INNER JOIN pg_class class ON class.oid = con.conrelid + INNER JOIN pg_namespace ns ON ns.oid = class.relnamespace +WHERE + con.contype IN ('p', 'u') AND + ns.nspname != 'pg_catalog' +ORDER BY 1, 2, 3; diff --git a/snippets/pulumi/commands.fish b/snippets/pulumi/commands.fish index 4b27cfc..4560913 100644 --- a/snippets/pulumi/commands.fish +++ b/snippets/pulumi/commands.fish @@ -65,3 +65,8 @@ pulumi stack export | jq -r '.deployment.resources[].provider' | grep -v 'aws::d # Avoid permission errors when deleting clusters with charts and stuff. PULUMI_K8S_DELETE_UNREACHABLE='true' pulumi destroy + +# Move rsources between stacks +pulumi state move --source 'organization/utils/dev' --dest 'organization/iam/dev' \ + 'urn:pulumi:dev::utils::aws:iam/role:Role::rdsToS3Exporter' \ + 'urn:pulumi:dev::utils::aws:iam/rolePolicy:RolePolicy::rdsToS3Exporter-allowExportingSnapshotsToS3'