chore(postgresql): dump acquired knowledge

This commit is contained in:
Michele Cereda
2024-11-01 20:56:26 +01:00
parent 2e5e2920fc
commit df47fc3d7d
4 changed files with 102 additions and 26 deletions

View File

@@ -17,6 +17,25 @@ docker run -d --name 'pgadmin' \
-e 'PGADMIN_DEFAULT_PASSWORD=password' \
'dpage/pgadmin4'
# Set up the credentials file
# Format => hostname:port:database:username:password
# Supports wildcards
cat <<EOF > ~/'.pgpass'
postgres.lan:5643:postgres:postgres:BananaORama
*:*:sales:elaine:modestPassword
EOF
chmod '600' ~/'.pgpass'
# Set up the per-user services file.
# do *not* use spaces around the '=' sign.
cat <<EOF > ~/'.pg_service.conf'
[prod]
host=prod.0123456789ab.eu-west-1.rds.amazonaws.com
port=5433
user=master
EOF
# Connect to DBs
psql 'postgres'
psql 'postgres' 'admin'
@@ -24,6 +43,7 @@ psql --host 'prod.db.lan' --port '5432' --username 'postgres' --database 'postgr
psql -h 'host.fqnd' -p '5432' -U 'admin' -d 'postgres' -W
psql 'postgresql://localhost:5433/games?sslmode=require'
psql 'host=host.fqdn port=5467 user=admin dbname=postgres'
psql "service=prod sslmode=require"
# List available databases
psql … --list

View File

@@ -23,25 +23,34 @@ LANGUAGE plpgsql
AS $$
DECLARE affected_rows INTEGER;
BEGIN
EXECUTE format('
WITH
ctids AS (
SELECT
ROW_NUMBER() OVER (),
ctid
FROM %I
),
shuffled_values AS (
SELECT
ROW_NUMBER() OVER (ORDER BY RANDOM()),
%I AS new_value
FROM %I
)
UPDATE %I
SET %I = shuffled_values.new_value
FROM shuffled_values JOIN ctids ON shuffled_values.row_number = ctids.row_number
WHERE %I.ctid = ctids.ctid
', table_name, column_name, table_name, table_name, column_name, table_name);
SET CONSTRAINTS ALL DEFERRED;
EXECUTE format(
'
WITH
ctids AS (
SELECT
ROW_NUMBER() OVER (),
ctid
FROM %I
),
shuffled_values AS (
SELECT
ROW_NUMBER() OVER (ORDER BY RANDOM()),
%I AS new_value
FROM %I
)
UPDATE %I
SET %I = shuffled_values.new_value
FROM shuffled_values JOIN ctids ON shuffled_values.row_number = ctids.row_number
WHERE %I.ctid = ctids.ctid
',
table_name,
column_name,
table_name,
table_name,
column_name,
table_name
);
GET DIAGNOSTICS affected_rows = ROW_COUNT;
RETURN affected_rows;
END;

View File

@@ -85,6 +85,7 @@ CREATE TABLE people (
);
-- Show table structure
-- Includes constraints
\d sales
\d+ clients
SELECT column_name, data_type, character_maximum_length FROM INFORMATION_SCHEMA.COLUMNS WHERE table_name = 'vendors';
@@ -290,11 +291,20 @@ SELECT setseed(0.25), round(random()::DECIMAL, 15) AS random_number; -- seed mu
-- Refer <https://www.postgresql.org/docs/current/sql-createfunction.html>
\df
\df+ to_char
\df+ hash*
SELECT routine_name FROM information_schema.routines WHERE routine_type = 'FUNCTION';
SELECT p.proname FROM pg_catalog.pg_namespace n JOIN pg_catalog.pg_proc p ON p.pronamespace = n.oid WHERE p.prokind = 'f';
CREATE OR REPLACE FUNCTION return_1() RETURNS INTEGER LANGUAGE SQL RETURN 1;
-- Show functions definition
\sf hash_numeric
\sf+ hashfloat8
-- Given hash_national_ids(country TEXT, table_name TEXT, column_name DEFAULT 'national_id')
SELECT hash_national_ids('estonia', 'clients');
SELECT hash_national_ids(country => 'estonia', table_name => 'clients', column_name => 'national_id');
-- Type casting
SELECT pg_typeof(10);
@@ -382,7 +392,20 @@ ALTER TABLE signups RENAME CONSTRAINT signups_customer_id_fkey TO something_blue
ALTER TABLE vendors SET CONSTRAINT vendors_value_uindex DEFERRED;
-- Show all constraints
-- Show all constraints in the current DB
SELECT
ns.nspname AS schema,
class.relname AS "table",
con.conname AS "constraint",
con.contype AS "type",
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 ns.nspname != 'pg_catalog'
ORDER BY 1, 2, 3;
-- Show all uniqueness constraints in the current DB
SELECT
ns.nspname AS schema,
class.relname AS "table",
@@ -393,6 +416,25 @@ 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
con.contype IN ('u') AND
ns.nspname != 'pg_catalog'
ORDER BY 1, 2, 3;
-- List all uniqueness constraints in a schema
SELECT
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 ('u') AND
ns.nspname = 'public'
ORDER BY 1, 2, 3;
-- Empty tables of their data
TRUNCATE TABLE sales;