Skip to content

Commit 1b492d6

Browse files
authored
feat: added config to run benchmarks (#3)
1 parent cab4d92 commit 1b492d6

File tree

4 files changed

+227
-0
lines changed

4 files changed

+227
-0
lines changed

benchmark/.gitignore

Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1 @@
1+
.env

benchmark/Dockerfile

Lines changed: 5 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,5 @@
1+
FROM alpine:latest
2+
3+
RUN apk --no-cache add postgresql-contrib
4+
5+
ENTRYPOINT [ "pgbench" ]

benchmark/README.md

Lines changed: 58 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,58 @@
1+
# Benchmark
2+
3+
This folder has a configuration to run benchmarks on Postgres dbsync. Docker is used to access the tool pgbench and bench.sql is some common queries.
4+
5+
## Compile docker image
6+
7+
To use the image is necessary to compile
8+
9+
```bash
10+
docker build -t pgbench .
11+
```
12+
13+
## Environment
14+
15+
The pgbench needs some environment variables to work, then create a file `.env` and set these envs below
16+
17+
| Key | Value |
18+
| ---------- | ----- |
19+
| PGDATABASE | |
20+
| PGHOST | |
21+
| PGPORT | |
22+
| PGUSER | |
23+
| PGPASSWORD | |
24+
25+
## Run benchmark
26+
27+
To run the benchmark it's necessary to run the docker image compiled before, but it's necessary to use some parameters of pgbench.
28+
29+
```bash
30+
docker run --env-file .env --network host --volume ./bench.sql:/bench.sql pgbench:latest -c 10 -T 5 -n -f /bench.sql
31+
```
32+
33+
- `-c` concurrences users
34+
- `-T` execution time(seconds)
35+
- `-n` enable for the custom scripts
36+
- `-f` script path
37+
38+
more parameters
39+
https://www.postgresql.org/docs/devel/pgbench.html
40+
41+
### Metrics example
42+
43+
The return when the command is finished
44+
45+
```
46+
transaction type: /bench.sql
47+
scaling factor: 1
48+
query mode: simple
49+
number of clients: 4
50+
number of threads: 1
51+
maximum number of tries: 1
52+
duration: 10 s
53+
number of transactions actually processed: 16
54+
number of failed transactions: 0 (0.000%)
55+
latency average = 1562.050 ms
56+
initial connection time = 3951.848 ms
57+
tps = 2.560738 (without initial connection time)
58+
```

benchmark/bench.sql

Lines changed: 163 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,163 @@
1+
--- Select latest epoch parameters
2+
select
3+
*
4+
from
5+
epoch_param ep
6+
order by
7+
ep.epoch_no desc
8+
limit 1;
9+
10+
--- Select assets by policy and apply filters by metadata
11+
with asset as (
12+
select
13+
ma_tx_mint.tx_id,
14+
encode(multi_asset.name, 'escape') as name,
15+
encode(multi_asset.policy, 'hex') as policy,
16+
multi_asset.fingerprint
17+
from
18+
multi_asset
19+
inner join
20+
ma_tx_mint on
21+
ma_tx_mint.ident = multi_asset.id
22+
where
23+
multi_asset.policy = '\x8f80ebfaf62a8c33ae2adf047572604c74db8bc1daba2b43f9a65635'
24+
),metadata as (
25+
select
26+
tx_metadata.tx_id,
27+
tx_metadata.json as metadata
28+
from
29+
tx_metadata
30+
where
31+
tx_metadata.tx_id in (select tx_id from asset)
32+
)
33+
select
34+
*,
35+
count(*) over () as count
36+
from
37+
asset
38+
inner join metadata on
39+
asset.tx_id = metadata.tx_id
40+
where
41+
jsonb_path_query_array(metadata.metadata,'$.*.*.type') ?| array['Orc']
42+
order by
43+
asset.name asc
44+
limit 20 offset 0;
45+
46+
--- Select total assets by policy from stake address
47+
select
48+
sum(ma_tx_out.quantity) as quantity,
49+
encode(multi_asset.policy, 'hex') as policy
50+
from
51+
utxo_view
52+
inner join
53+
stake_address on stake_address.id = utxo_view.stake_address_id
54+
inner join
55+
ma_tx_out on ma_tx_out.tx_out_id = utxo_view.id
56+
inner join
57+
multi_asset on multi_asset.id = ma_tx_out.ident
58+
where
59+
stake_address."view" = 'stake1u90nkx5yw6qkpas3kxa0wcql93axph8fetw20l0j2ntszucgg4rr2'
60+
and
61+
multi_asset.policy = '\xb7761c472eef3b6e0505441efaf940892bb59c01be96070b0a0a89b3'
62+
group by multi_asset.policy;
63+
64+
--- Select all assets from a stake address
65+
select
66+
ma_tx_out.tx_out_id,
67+
ma_tx_out.quantity,
68+
encode(multi_asset.name, 'escape') as name,
69+
encode(multi_asset.policy, 'hex') as policy,
70+
multi_asset.fingerprint,
71+
tx_metadata.json as metadata,
72+
count(*) over () as count
73+
from
74+
utxo_view
75+
inner join
76+
stake_address on stake_address.id = utxo_view.stake_address_id
77+
inner join
78+
ma_tx_out on ma_tx_out.tx_out_id = utxo_view.id
79+
inner join
80+
multi_asset on multi_asset.id = ma_tx_out.ident
81+
inner join
82+
ma_tx_mint on ma_tx_mint.ident = multi_asset.id
83+
inner join
84+
tx_metadata on tx_metadata.tx_id = ma_tx_mint.tx_id
85+
where
86+
stake_address.view = 'stake1u90nkx5yw6qkpas3kxa0wcql93axph8fetw20l0j2ntszucgg4rr2'
87+
order by
88+
multi_asset.name asc
89+
limit 20 offset 1;
90+
91+
--- Select all utxos from a stake address
92+
select
93+
tx_out.id,
94+
tx.hash,
95+
tx_out.index,
96+
tx_out.address,
97+
tx_out.value
98+
from
99+
tx_out
100+
left join
101+
tx_in on tx_out.tx_id = tx_in.tx_out_id and tx_out.index::smallint = tx_in.tx_out_index::smallint
102+
left join
103+
tx on tx.id = tx_out.tx_id
104+
left join
105+
block on tx.block_id = block.id
106+
inner join
107+
stake_address on stake_address.id = tx_out.stake_address_id
108+
where
109+
tx_in.tx_in_id is null and
110+
block.epoch_no is not null and
111+
stake_address.view = 'stake1u90nkx5yw6qkpas3kxa0wcql93axph8fetw20l0j2ntszucgg4rr2';
112+
113+
--- Select slot number of the most recent block
114+
select
115+
slot_no
116+
from
117+
block
118+
where
119+
block_no is not null
120+
order by
121+
block_no desc
122+
limit 1;
123+
124+
--- Select current valid pools
125+
select
126+
*
127+
from
128+
pool_update
129+
where
130+
registered_tx_id in (select max(registered_tx_id) from pool_update group by hash_id)
131+
and
132+
not exists(
133+
select
134+
*
135+
from
136+
pool_retire
137+
where
138+
pool_retire.hash_id = pool_update.hash_id
139+
and
140+
pool_retire.retiring_epoch <= (select max (epoch_no) from block)
141+
);
142+
143+
--- Select the stake address for a given Shelley address
144+
select
145+
stake_address.id as stake_address_id,
146+
tx_out.address,
147+
stake_address.view as stake_address
148+
from
149+
tx_out
150+
inner join
151+
stake_address on tx_out.stake_address_id = stake_address.id
152+
where
153+
address = 'addr1q8u4wgd8qplhxpt4xm2l8yagy5ng7veurwrns2ysh03zuh2l8vdgga5pvrmprvd67asp7tr6vrwwnjku5l7ly4xhq9esr9h59t';
154+
155+
--- Select transaction outputs for specified transaction hash
156+
select
157+
tx_out.*
158+
from
159+
tx_out
160+
inner join
161+
tx on tx_out.tx_id = tx.id
162+
where
163+
tx.hash = '\xabd21556d9bb817d436e33a5fa32619702633dc809e707a5297566e9d74d57c1';

0 commit comments

Comments
 (0)