Postgres¶
Ubijanie zapytań¶
1 2 | # Zabije wszystko oprócz nas i siebie ( su - postgres -c psql )
select pg_terminate_backend(pid) from pg_stat_activity where usename!='postgres';
|
Diagnostyka¶
1 2 3 4 5 | # ilosc polaczen do bazy
select count(*) from pg_stat_activity;
# Zapytanie ktore trwaja dluzej niz 5 min
select * from pg_stat_activity where query_start < now() - interval '5 minutes' and current_query ~ '^SELECT'
|
Odtworzenie bazy¶
1 2 3 4 5 | # Zmiana użytkownika w dupmie
pg_dump -s baza.dump | grep -i 'owner to' | sed -e 's/OWNER TO .*;/ OWNER TO leszek;/i'
# Odtworzenie bazy
pg_restore -Fc baza.dump -O --role leszek -d mojabaza
|
Dokładniejsze informacje o kontach¶
1 2 3 4 5 6 7 8 9 10 11 12 | SELECT r.rolname, r.rolsuper, r.rolinherit,
r.rolcreaterole, r.rolcreatedb, r.rolcanlogin,
r.rolconnlimit, r.rolvaliduntil,
ARRAY(SELECT b.rolname
FROM pg_catalog.pg_auth_members m
JOIN pg_catalog.pg_roles b ON (m.roleid = b.oid)
WHERE m.member = r.oid) as memberof
, r.rolreplication
, r.rolbypassrls
FROM pg_catalog.pg_roles r
WHERE r.rolname !~ '^pg_'
ORDER BY 1;
|
Wyświetlenie blokowanych zapytan¶
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 | SELECT blocked_locks.pid AS blocked_pid,
blocked_activity.usename AS blocked_user,
blocking_locks.pid AS blocking_pid,
blocking_activity.usename AS blocking_user,
blocked_activity.query AS blocked_statement,
blocking_activity.query AS current_statement_in_blocking_process
FROM pg_catalog.pg_locks blocked_locks
JOIN pg_catalog.pg_stat_activity blocked_activity ON blocked_activity.pid = blocked_locks.pid
JOIN pg_catalog.pg_locks blocking_locks
ON blocking_locks.locktype = blocked_locks.locktype
AND blocking_locks.DATABASE IS NOT DISTINCT FROM blocked_locks.DATABASE
AND blocking_locks.relation IS NOT DISTINCT FROM blocked_locks.relation
AND blocking_locks.page IS NOT DISTINCT FROM blocked_locks.page
AND blocking_locks.tuple IS NOT DISTINCT FROM blocked_locks.tuple
AND blocking_locks.virtualxid IS NOT DISTINCT FROM blocked_locks.virtualxid
AND blocking_locks.transactionid IS NOT DISTINCT FROM blocked_locks.transactionid
AND blocking_locks.classid IS NOT DISTINCT FROM blocked_locks.classid
AND blocking_locks.objid IS NOT DISTINCT FROM blocked_locks.objid
AND blocking_locks.objsubid IS NOT DISTINCT FROM blocked_locks.objsubid
AND blocking_locks.pid != blocked_locks.pid
JOIN pg_catalog.pg_stat_activity blocking_activity ON blocking_activity.pid = blocking_locks.pid
WHERE NOT blocked_locks.GRANTED;
|
Odświeżenie widoków¶
1 2 3 4 5 6 7 8 9 10 11 12 13 | # Wyświetlenie widoków
select schemaname as schema_name,
matviewname as view_name,
matviewowner as owner,
ispopulated as is_populated,
definition
from pg_matviews
order by schema_name,
view_name;
# Odświeżenie
REFRESH MATERIALIZED VIEW view_products;
|
Uprawnienia¶
1 2 3 4 5 | # Nadanie / odebranie
GRANT CONNECT ON DATABASE mojabaza TO username;
GRANT USAGE ON SCHEMA public TO username;
GRANT SELECT ON table_name TO username;
REVOKE ALL PRIVILEGES ON mojabaza from leszek;
|
Zmiana właściciela¶
1 2 3 4 | for tbl in `psql -qAt -c "select tablename from pg_tables where schemaname = 'public';" YOUR_DB` ; do psql -c "alter table \"$tbl\" owner to NEW_OWNER" YOUR_DB ; done
for tbl in `psql -qAt -c "select sequence_name from information_schema.sequences where sequence_schema = 'public';" YOUR_DB` ; do psql -c "alter table \"$tbl\" owner to NEW_OWNER" YOUR_DB ; done
for tbl in `psql -qAt -c "select table_name from information_schema.views where table_schema = 'public';" YOUR_DB` ; do psql -c "alter table \"$tbl\" owner to NEW_OWNER" YOUR_DB ; done
for tbl in `psql -qAt -c "select table_name from information_schema.views where table_schema = 'public';" $db` ; do psql -c "alter function \"$tbl\" owner to $db" $db ; done
|
Insert/Update¶
1 2 3 | Begin;
UPDATE films SET kind = 'Dramatic' WHERE kind = 'Drama';
Commit;
|