Skip to content

Commit

Permalink
feat: add more metrics for live-migration
Browse files Browse the repository at this point in the history
Signed-off-by: Harkishen-Singh <harkishensingh@hotmail.com>

This commit adds following metrics to migration evaluation script
that are helpful for evaluating whether a database is fit for
live-migration strategy:
- Rate of inserts, updates, deletes and transactions per second
- Do compressed chunks have mutable compression
- Do tables attributes have NaN, Infinity or -Infinity
- WAL activity of the source database
- Do tables have generated columns
  • Loading branch information
Harkishen-Singh committed Apr 4, 2024
1 parent 4ec4cc8 commit 02de50a
Show file tree
Hide file tree
Showing 2 changed files with 134 additions and 11 deletions.
17 changes: 15 additions & 2 deletions README.md
Original file line number Diff line number Diff line change
Expand Up @@ -11,10 +11,14 @@ some information about its current state. You can collect this information
by running the following command:

```sh
curl -sL https://assets.timescale.com/releases/migration/evaluate.py | python3 - "<POSTGRES_URI>" > report.txt
curl -sL https://assets.timescale.com/releases/migration/evaluate.py | python3 - "<POSTGRES_URI>" <wait-duration> > report.txt
```

This command will:
where
- `<POSTGRES_URI>` is the URI of your source database.
- `<wait-duration>` is the amount of time in _seconds_ to consider while computing rate based metrics, eg, rate of transactions per second. This argument is optional and defaults to 1 minute.

The above command will:
- Download the latest evaluation script
- Run queries against your Postgres database
- Save the results necessary for evaluating the suitable migration strategy to a file named "report.txt"
Expand All @@ -38,4 +42,13 @@ Num TimescaleDB space dimensions: 2
TimescaleDB extension schema: public
TimescaleDB features: {hypertables,continuous_aggregates,retention,compression,background_jobs}
Unsupported extensions in Timescale Cloud: [{"aiven_extras" : "1.1.12"}]
Rate of inserts, updates, deletes and transactions (per sec): 10791.750, 0.000, 0.000, 43.667
Do compressed chunks have mutable (insert/update/delete) compression*: f
Do tables have generated columns: f
Do tables attributes have NaN, Infinity or -Infinity*: f
WAL activity: 19786.500 wal_records_per_sec, 2.172 wal_megabytes_per_sec
```

Note: Metrics with an asterisk (*) will require further confirmation from the user.
This is because they represent the temporary state of the database, and the actual answer
may vary depending on the applications.
128 changes: 119 additions & 9 deletions evaluate.py
Original file line number Diff line number Diff line change
Expand Up @@ -163,13 +163,119 @@
select json_agg(json_build_object(extname, extversion)) from pg_extension
where extname not in ({",".join([f"'{ext}'" for ext in SUPPORTED_EXTENSIONS])})
""",
}, {
"name": "Do tables have generated columns",
"query": f"""
select exists(select 1 from information_schema.columns where is_generated = 'ALWAYS')
"""
}, {
"name": "Do tables attributes have NaN, Infinity or -Infinity*",
"query": f"""
select exists (
select 1 from pg_stats where
schemaname not in (
'_timescaledb_internal', '_timescaledb_config', '_timescaledb_catalog', '_timescaledb_cache',
'timescaledb_experimental', 'timescaledb_information', '_timescaledb_functions',
'information_schema', 'pg_catalog')
and
(
exists (
select 1 from unnest(most_common_vals::text::text[]) as v
where
v IN ('NaN', 'Infinity', '-Infinity')
)
or
exists (
select 1 from unnest(histogram_bounds::text::text[]) as h
where
h IN ('NaN', 'Infinity', '-Infinity')
)
)
)
"""
}, {
"name": "Rate of inserts, updates, deletes and transactions (per sec)",
"query": f"""
create temp table _mig_eval_t (
n int, n_tup_ins numeric, n_tup_upd numeric, n_tup_del numeric, xact_commit numeric
);
begin;
insert into _mig_eval_t
select 1, sum(n_tup_ins) n_tup_ins, sum(n_tup_upd) n_tup_upd, sum(n_tup_del) n_tup_del, d.xact_commit
from pg_stat_user_tables u join pg_stat_database d on true
where
u.relname not in ('_mig_eval_t') AND
u.schemaname not in (
'_timescaledb_config', '_timescaledb_catalog', '_timescaledb_cache',
'timescaledb_experimental', 'timescaledb_information', '_timescaledb_functions',
'information_schema', 'pg_catalog') AND
d.datname = current_database()
group by d.xact_commit;
commit;
select pg_sleep(@wait@);
begin;
insert into _mig_eval_t
select 2, sum(n_tup_ins) n_tup_ins, sum(n_tup_upd) n_tup_upd, sum(n_tup_del) n_tup_del, d.xact_commit
from pg_stat_user_tables u join pg_stat_database d on true
where
u.relname not in ('_mig_eval_t') AND
u.schemaname not in (
'_timescaledb_config', '_timescaledb_catalog', '_timescaledb_cache',
'timescaledb_experimental', 'timescaledb_information', '_timescaledb_functions',
'information_schema', 'pg_catalog') AND
d.datname = current_database()
group by d.xact_commit;
commit;
with before as (
select * from _mig_eval_t where n = 1
), after as (
select * from _mig_eval_t where n = 2
)
select
round((after.n_tup_ins - before.n_tup_ins) / @wait@, 3) inserts_per_sec,
' ' || round((after.n_tup_upd - before.n_tup_upd) / @wait@, 3) updates_per_sec,
' ' || round((after.n_tup_del - before.n_tup_del) / @wait@, 3) deletes_per_sec,
' ' || round((after.xact_commit - before.xact_commit) / @wait@, 3) txns_per_sec
from after, before;
""",
}, {
"name": "WAL activity",
"query": f"""
create temp table _mig_eval_w (n int, wal_records numeric, wal_bytes numeric);
begin;
insert into _mig_eval_w
select 1, wal_records, wal_bytes from pg_stat_wal;
commit;
select pg_sleep(@wait@);
begin;
insert into _mig_eval_w
select 2, wal_records, wal_bytes from pg_stat_wal;
commit;
with before as (
select * from _mig_eval_w where n = 1
), after as (
select * from _mig_eval_w where n = 2
)
select
round((after.wal_records - before.wal_records) / @wait@, 3)::text || ' wal_records_per_sec',
' ' || round((after.wal_bytes - before.wal_bytes) / (@wait@ * 1024 * 1024), 3)::text || ' wal_megabytes_per_sec'
from after, before;
"""
}
]

POSTGRES_URI = ""

def execute(sql: str) -> str:
cmd = ["psql", "-X", "-A", "-t", "-v", "ON_ERROR_STOP=1", "--echo-errors", "-d", POSTGRES_URI, "-c", sql]
cmd = ["psql", "-X", "-A", "-t", "-q", "-F", ",", "-v", "ON_ERROR_STOP=1", "--echo-errors", "-d", POSTGRES_URI, "-c", sql]
result = subprocess.run(cmd, stdout=subprocess.PIPE, stderr=subprocess.PIPE, text=True)
output = str(result.stdout)[:-1].strip()
if result.returncode != 0:
Expand All @@ -185,13 +291,17 @@ def test_conn() -> bool:
sys.exit(1)

if __name__ == "__main__":
if len(sys.argv) > 1:
POSTGRES_URI = sys.argv[1]
else:
print('POSTGRES_URI not found. Please provide it as an argument\nEg: python3 evaluate.py "<POSTGRES_URI>"', file=sys.stderr)
sys.exit(1)

wait_duration = 60
match len(sys.argv):
case 3:
POSTGRES_URI = sys.argv[1]
wait_duration = int(sys.argv[2])
case 2:
POSTGRES_URI = sys.argv[1]
case _:
print('POSTGRES_URI not found. Please provide it as an argument\nEg: python3 evaluate.py "<POSTGRES_URI>"', file=sys.stderr)
sys.exit(1)
test_conn()

for query in QUERIES:
print(f"{query['name']}: {execute(query['query'])}", file=sys.stdout)
sql = query['query'].replace("@wait@", str(wait_duration))
print(f"{query['name']}: {execute(sql)}", file=sys.stdout)

0 comments on commit 02de50a

Please sign in to comment.