Skip to content

Commit 7195c7d

Browse files
authored
Merge branch 'master' into activity
2 parents d8ec239 + 73439d6 commit 7195c7d

File tree

13 files changed

+431
-47
lines changed

13 files changed

+431
-47
lines changed

.circleci/config.yml

Lines changed: 8 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -7,7 +7,7 @@ jobs:
77
environment:
88
- PGHOST: 127.0.0.1
99
- PGUSER: root
10-
- image: circleci/postgres:9.6
10+
- image: circleci/postgres:10
1111
environment:
1212
- POSTGRES_USER: root
1313
- POSTGRES_DB: test
@@ -30,4 +30,10 @@ jobs:
3030
- run:
3131
name: Tests
3232
command: |
33-
diff -b test/regression/3_activity.out <(psql test -f ~/postgres_dba/sql/3_activity.sql | grep User)
33+
# echo "\set postgres_dba_wide true" > ~/.psqlrc
34+
#for f in ~/postgres_dba/sql/*; do psql test -f "$f">/dev/null; done
35+
#echo "\set postgres_dba_wide false" > ~/.psqlrc
36+
#for f in ~/postgres_dba/sql/*; do psql test -f "$f">/dev/null; done
37+
diff -b test/regression/1_basic.out <(psql test -f warmup.psql -f ~/postgres_dba/sql/1_basic.sql | grep Role)
38+
diff -b test/regression/p1_alignment_padding.out <(psql test -f warmup.psql -f ~/postgres_dba/sql/p1_alignment_padding.sql | grep align)
39+
diff -b test/regression/a1_activity.out <(psql test -f warmup.psql -f ~/postgres_dba/sql/a1_activity.sql | grep User)

README.md

Lines changed: 7 additions & 7 deletions
Original file line numberDiff line numberDiff line change
@@ -1,13 +1,15 @@
1-
[![CircleCI](https://circleci.com/gh/NikolayS/postgres_dba/tree/master.svg?style=svg)](https://circleci.com/gh/NikolayS/postgres_dba/tree/master)
1+
[![CircleCI](https://circleci.com/gh/NikolayS/postgres_dba.svg?style=svg)](https://circleci.com/gh/NikolayS/postgres_dba)
22
# postgres_dba (PostgresDBA)
33

4-
The missing set of useful tools for Postgres DBA and non-Postgres developers.
4+
The missing set of useful tools for Postgres DBA and mere mortals.
55

66
:warning: The project is in its very early stage. If you have great ideas, feel free to create a pull request or open an issue.
77

8+
<img width="709" alt="screen shot 2018-03-17 at 14 34 04" src="https://user-images.githubusercontent.com/1345402/37560150-78b4b24e-29f0-11e8-9b3f-7d68b13631e1.png">
9+
810
## Questions?
911

10-
Questions? Ideas? Write me: samokhvalov@gmail.com, Nikolay Samokhvalov.
12+
Questions? Ideas? Contact me: samokhvalov@gmail.com, Nikolay Samokhvalov.
1113

1214
## Credits
1315

@@ -46,13 +48,11 @@ And type `:dba <Enter>` in psql. (Or `\i /path/to/postgres_dba/start.psql` if yo
4648

4749
– it will open interactive menu.
4850

49-
<img width="779" alt="screen shot 2018-01-05 at 13 14 30" src="https://user-images.githubusercontent.com/1345402/34628761-6b98b988-f21a-11e7-8e5c-ab2580389a5c.png">
50-
5151
### Connect to Remote Postgres Server
5252
What to do if you need to connect to a remote Postgres server? Usually, Postgres is behind a firewall and/or doesn't listen to a public network interface. So you need to be able to connect to the server using SSH. If you can do it, then just create SSH tunnel (assuming that Postgres listens to default port 5432 on that server:
5353

5454
```bash
55-
ssh -fNTML 9432:localhost:5432 you-server.com
55+
ssh -fNTML 9432:localhost:5432 sshusername@you-server.com
5656
```
5757

5858
Then, just launch psql, connecting to port 9432 at localhost:
@@ -76,7 +76,7 @@ And then:
7676
## How to Extend (Add More Queries)
7777
You can add your own useful SQL queries and use them from the main menu. Just add your SQL code to `./sql` directory. The filename should start with some 1 or 2-letter code, followed by underscore and some additional arbitrary words. Extension should be `.sql`. Example:
7878
```
79-
sql/f1_funny_query.sql
79+
 sql/f1_cool_query.sql
8080
```
8181
– this will give you an option "f1" in the main menu. The very first line in the file should be an SQL comment (starts with `--`) with the query description. It will automatically appear in the menu.
8282

init/generate.sh

Lines changed: 19 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -2,16 +2,31 @@
22
# Generate start.psql based on the contents of "sql" directory
33
DIR="$( cd "$( dirname "${BASH_SOURCE[0]}" )" && pwd )"
44

5+
WARMUP="warmup.psql"
56
OUT="start.psql"
67

8+
echo "" > "$WARMUP"
9+
echo "" > "$OUT"
10+
711
cd "$DIR/.."
8-
cat > "$OUT" <<- VersCheck
12+
cat > "$WARMUP" <<- VersCheck
913
-- check if "\if" is supported (psql 10+)
1014
\if false
1115
\echo cannot work, you need psql version 10+ (Postgres server can be older)
1216
select 1/0;
1317
\endif
1418
19+
select regexp_replace(version(), '^PostgreSQL (\d+\.\d+).*$', e'\\\\1')::numeric >= 10 as postgres_dba_pgvers_10plus \gset
20+
\if :postgres_dba_pgvers_10plus
21+
\set postgres_dba_last_wal_receive_lsn pg_last_wal_receive_lsn
22+
\set postgres_dba_last_wal_replay_lsn pg_last_wal_replay_lsn
23+
\set postgres_dba_is_wal_replay_paused pg_is_wal_replay_paused
24+
\else
25+
\set postgres_dba_last_wal_receive_lsn pg_last_xlog_receive_location
26+
\set postgres_dba_last_wal_replay_lsn pg_last_xlog_replay_location
27+
\set postgres_dba_is_wal_replay_paused pg_is_xlog_replay_paused
28+
\endif
29+
1530
-- TODO: improve work with custom GUCs for Postgres 9.5 and older
1631
select regexp_replace(version(), '^PostgreSQL (\d+\.\d+).*$', e'\\\\1')::numeric >= 9.6 as postgres_dba_pgvers_96plus \gset
1732
\if :postgres_dba_pgvers_96plus
@@ -22,6 +37,9 @@ select regexp_replace(version(), '^PostgreSQL (\d+\.\d+).*$', e'\\\\1')::numeric
2237
reset client_min_messages;
2338
\endif
2439
VersCheck
40+
41+
echo "\\ir $WARMUP" >> "$OUT"
42+
2543
echo "\\echo '\\033[1;35mMenu:\\033[0m'" >> "$OUT"
2644
for f in ./sql/*.sql
2745
do

sql/1_basic.sql

Lines changed: 25 additions & 8 deletions
Original file line numberDiff line numberDiff line change
@@ -1,36 +1,53 @@
1-
--Basic Node Information (master/replica, lag, DB size, tmp files)
1+
--Node Information: master/replica, lag, DB size, tmp files, etc
22
with data as (
33
select s.*
44
from pg_stat_database s
55
where s.datname = current_database()
66
)
7-
select 'Database Name' as metric, datname as value from data
8-
union all
9-
select 'Database Version' as metric, version() as value
7+
select 'Postgres Version' as metric, version() as value
108
union all
119
select
1210
'Role' as metric,
1311
case
1412
when pg_is_in_recovery() then 'Replica' || ' (delay: '
1513
|| ((((case
16-
when pg_last_xlog_receive_location() = pg_last_xlog_replay_location() then 0
14+
when :postgres_dba_last_wal_receive_lsn() = :postgres_dba_last_wal_replay_lsn() then 0
1715
else extract (epoch from now() - pg_last_xact_replay_timestamp())
1816
end)::int)::text || ' second')::interval)::text
19-
|| '; paused: ' || pg_is_xlog_replay_paused()::text || ')'
17+
|| '; paused: ' || :postgres_dba_is_wal_replay_paused()::text || ')'
2018
else 'Master'
2119
end as value
2220
union all
21+
select 'Started At', pg_postmaster_start_time()::timestamptz(0)::text
22+
union all
23+
select 'Uptime', (now() - pg_postmaster_start_time())::interval(0)::text
24+
union all
25+
select 'Database Name' as metric, datname as value from data
26+
union all
2327
select 'Database Size', pg_catalog.pg_size_pretty(pg_catalog.pg_database_size(current_database()))
2428
union all
29+
select 'Installed Extensions', (
30+
with exts as (
31+
select extname || ' (' || extversion || ')' e, (-1 + row_number() over (order by extname)) / 5 i from pg_extension
32+
), lines(l) as (
33+
select string_agg(e, ', ' order by i) l from exts group by i
34+
)
35+
select string_agg(l, e'\n') from lines
36+
)
37+
union all
2538
select 'Cache Effectiveness', (round(blks_hit * 100::numeric / (blks_hit + blks_read), 2))::text || '%' from data
2639
union all
2740
select 'Successful Commits', (round(xact_commit * 100::numeric / (xact_commit + xact_rollback), 2))::text || '%' from data
2841
union all
2942
select 'Conflicts', conflicts::text from data
3043
union all
31-
select 'Temp Files: total size (total number of files)', (pg_size_pretty(temp_bytes)::text || ' (' || temp_files::text || ')') from data
44+
select 'Temp Files: total size', pg_size_pretty(temp_bytes)::text from data
45+
union all
46+
select 'Temp Files: total number of files', temp_files::text from data
3247
union all
3348
select 'Deadlocks', deadlocks::text from data
3449
union all
35-
select 'Stat Since', stats_reset::text from data
50+
select 'Stats Since', stats_reset::timestamptz(0)::text from data
51+
union all
52+
select 'Stats Age', (now() - stats_reset)::interval(0)::text from data
3653
;

sql/2_table_sizes.sql

Lines changed: 25 additions & 8 deletions
Original file line numberDiff line numberDiff line change
@@ -1,8 +1,9 @@
1-
--General Table Size Information
1+
--Table Size
22

33
with data as (
44
select
55
c.oid,
6+
(select spcname from pg_tablespace where oid = reltablespace) as tblspace,
67
nspname as schema_name,
78
relname as table_name,
89
c.reltuples as row_estimate,
@@ -12,10 +13,11 @@ with data as (
1213
pg_total_relation_size(c.oid) - pg_indexes_size(c.oid) - coalesce(pg_total_relation_size(reltoastrelid), 0) as table_bytes
1314
from pg_class c
1415
left join pg_namespace n on n.oid = c.relnamespace
15-
where relkind = 'r'
16+
where relkind = 'r' and nspname <> 'pg_catalog'
1617
), data2 as (
1718
select
1819
null::oid as oid,
20+
null as tblspace,
1921
null as schema_name,
2022
'*** TOTAL ***' as table_name,
2123
sum(row_estimate) as row_estimate,
@@ -25,23 +27,37 @@ with data as (
2527
sum(table_bytes) as table_bytes
2628
from data
2729
union all
28-
select null::oid, null, null, null, null, null, null, null
30+
select
31+
null::oid as oid,
32+
null,
33+
null as schema_name,
34+
' tablespace: [' || coalesce(tblspace, 'pg_default') || ']' as table_name,
35+
sum(row_estimate) as row_estimate,
36+
sum(total_bytes) as total_bytes,
37+
sum(index_bytes) as index_bytes,
38+
sum(toast_bytes) as toast_bytes,
39+
sum(table_bytes) as table_bytes
40+
from data
41+
where (select count(distinct coalesce(tblspace, 'pg_default')) from data) > 1 -- don't show this part if there are no custom tablespaces
42+
group by tblspace
43+
union all
44+
select null::oid, null, null, null, null, null, null, null, null
2945
union all
3046
select * from data
3147
)
3248
select
33-
coalesce(nullif(schema_name, 'public') || '.', '') || table_name as "Table",
49+
coalesce(nullif(schema_name, 'public') || '.', '') || table_name || coalesce(' [' || tblspace || ']', '') as "Table",
3450
'~' || case
3551
when row_estimate > 10^12 then round(row_estimate::numeric / 10^12::numeric, 0)::text || 'T'
3652
when row_estimate > 10^9 then round(row_estimate::numeric / 10^9::numeric, 0)::text || 'B'
3753
when row_estimate > 10^6 then round(row_estimate::numeric / 10^6::numeric, 0)::text || 'M'
3854
when row_estimate > 10^3 then round(row_estimate::numeric / 10^3::numeric, 0)::text || 'k'
3955
else row_estimate::text
4056
end as "Rows",
41-
pg_size_pretty(total_bytes) || ' (' || round(100 * total_bytes::numeric / sum(total_bytes) over (partition by (schema_name is null)), 2)::text || '%)' as "Total Size",
42-
pg_size_pretty(table_bytes) || ' (' || round(100 * table_bytes::numeric / sum(table_bytes) over (partition by (schema_name is null)), 2)::text || '%)' as "Table Size",
43-
pg_size_pretty(index_bytes) || ' (' || round(100 * index_bytes::numeric / sum(index_bytes) over (partition by (schema_name is null)), 2)::text || '%)' as "Index(es) Size",
44-
pg_size_pretty(toast_bytes) || ' (' || round(100 * toast_bytes::numeric / sum(toast_bytes) over (partition by (schema_name is null)), 2)::text || '%)' as "TOAST Size"
57+
pg_size_pretty(total_bytes) || ' (' || round(100 * total_bytes::numeric / sum(total_bytes) over (partition by (schema_name is null), left(table_name, 3) = '***'), 2)::text || '%)' as "Total Size",
58+
pg_size_pretty(table_bytes) || ' (' || round(100 * table_bytes::numeric / sum(table_bytes) over (partition by (schema_name is null), left(table_name, 3) = '***'), 2)::text || '%)' as "Table Size",
59+
pg_size_pretty(index_bytes) || ' (' || round(100 * index_bytes::numeric / sum(index_bytes) over (partition by (schema_name is null), left(table_name, 3) = '***'), 2)::text || '%)' as "Index(es) Size",
60+
pg_size_pretty(toast_bytes) || ' (' || round(100 * toast_bytes::numeric / sum(toast_bytes) over (partition by (schema_name is null), left(table_name, 3) = '***'), 2)::text || '%)' as "TOAST Size"
4561
\if :postgres_dba_wide
4662
,
4763
row_estimate,
@@ -51,6 +67,7 @@ select
5167
toast_bytes,
5268
schema_name,
5369
table_name,
70+
tblspace,
5471
oid
5572
\endif
5673
from data2

sql/3_load_profiles.sql

Lines changed: 100 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,100 @@
1+
--Load Profile
2+
3+
with data as (
4+
select
5+
s.relname as table_name,
6+
s.schemaname as schema_name,
7+
(select spcname from pg_tablespace where oid = reltablespace) as tblspace,
8+
*,
9+
case when n_tup_upd = 0 then null else n_tup_hot_upd::numeric / n_tup_upd end as upd_hot_ratio,
10+
seq_tup_read + coalesce(idx_tup_fetch, 0) - n_tup_del - n_tup_upd as tuples_selected,
11+
seq_tup_read + coalesce(idx_tup_fetch, 0) + n_tup_ins as processed_tup_total -- we don't add _del and _upd here (already counted via seq_ & idx_)
12+
from pg_stat_user_tables s
13+
join pg_class c on c.oid = relid
14+
), data2 as (
15+
select
16+
0 as ord,
17+
'*** TOTAL ***' as table_name,
18+
null as schema_name,
19+
null as tblspace,
20+
sum(seq_tup_read) as seq_tup_read,
21+
sum(idx_tup_fetch) as idx_tup_fetch,
22+
sum(tuples_selected) as tuples_selected,
23+
sum(n_tup_ins) as n_tup_ins,
24+
sum(n_tup_del) as n_tup_del,
25+
sum(n_tup_upd) as n_tup_upd,
26+
sum(n_tup_hot_upd) as n_tup_hot_upd,
27+
avg(upd_hot_ratio) as upd_hot_ratio,
28+
sum(processed_tup_total) as processed_tup_total
29+
from data
30+
union all
31+
select
32+
1 as ord,
33+
' tablespace: [' || coalesce(tblspace, 'pg_default') || ']' as table_name,
34+
null as schema_name,
35+
null, -- we don't need to pass real tblspace value for this aggregated record further
36+
sum(seq_tup_read) as seq_tup_read,
37+
sum(idx_tup_fetch) as idx_tup_fetch,
38+
sum(tuples_selected) as tuples_selected,
39+
sum(n_tup_ins) as n_tup_ins,
40+
sum(n_tup_del) as n_tup_del,
41+
sum(n_tup_upd) as n_tup_upd,
42+
sum(n_tup_hot_upd) as n_tup_hot_upd,
43+
avg(upd_hot_ratio) as upd_hot_ratio,
44+
sum(processed_tup_total) as processed_tup_total
45+
from data
46+
where (select count(distinct coalesce(tblspace, 'pg_default')) from data) > 1 -- don't show this part if there are no custom tablespaces
47+
group by tblspace
48+
union all
49+
select 3, null, null, null, null, null, null, null, null, null, null, null, null
50+
union all
51+
select 4, table_name, schema_name, tblspace, seq_tup_read, idx_tup_fetch, tuples_selected, n_tup_ins, n_tup_del, n_tup_upd, n_tup_hot_upd, upd_hot_ratio, processed_tup_total
52+
from data
53+
)
54+
select
55+
coalesce(nullif(schema_name, 'public') || '.', '') || table_name || coalesce(' [' || tblspace || ']', '') as "Table",
56+
(
57+
with ops as (
58+
select * from data2 d2 where d2.schema_name is not distinct from data2.schema_name and d2.table_name = data2.table_name
59+
), ops_ratios(opname, ratio) as (
60+
select
61+
'select',
62+
case when processed_tup_total > 0 then tuples_selected::numeric / processed_tup_total else 0 end
63+
from ops
64+
union all
65+
select
66+
'insert',
67+
case when processed_tup_total > 0 then n_tup_ins::numeric / processed_tup_total else 0 end
68+
from ops
69+
union all
70+
select
71+
'delete',
72+
case when processed_tup_total > 0 then n_tup_del::numeric / processed_tup_total else 0 end
73+
from ops
74+
union all
75+
select
76+
'update',
77+
case when processed_tup_total > 0 then n_tup_upd::numeric / processed_tup_total else 0 end
78+
from ops
79+
)
80+
select
81+
case
82+
when ratio > .7 then upper(opname) || ' ~' || round(100 * ratio, 2)::text || '%'
83+
else 'Mixed: ' || (
84+
select string_agg(upper(left(opname, 1)) || ' ~' || round(100 * ratio, 2)::text || '%', ', ' order by ratio desc)
85+
from (select * from ops_ratios where ratio > .2) _
86+
)
87+
end
88+
from ops_ratios
89+
order by ratio desc
90+
limit 1
91+
) as "Load Type",
92+
processed_tup_total as "Total (S+I+D+U)",
93+
tuples_selected as "SELECTed",
94+
n_tup_ins as "INSERTed",
95+
n_tup_del as "DELETEd",
96+
n_tup_upd as "UPDATEd",
97+
round(100 * upd_hot_ratio, 2) as "HOT-updated, %",
98+
case when seq_tup_read + coalesce(idx_tup_fetch, 0) > 0 then round(100 * seq_tup_read::numeric / (seq_tup_read + coalesce(idx_tup_fetch, 0)), 2) else 0 end as "SeqScan, %"
99+
from data2
100+
order by ord, processed_tup_total desc;

0 commit comments

Comments
 (0)