postgres schema fixes after moving to self-operated PostgreSQL (#57)

* remove indices from migration.sql which here never created

* BREAKING: make transaction_id the primary key in transactions lookup table

* use varchar in postgres.rs

* add "NOT NULL" constraint wherever possible

* fix small accounts lookup table naming

* fly app for migration

see https://github.com/blockworks-foundation/BankingStageErrorsTrackingSidecar/issues/56

* autovacuum settings

* databse init script

* explain query_user role

* tune toast_tuple_target and comment on page size

* minor fixes

* dba queries

* jot down the fly machine config

* restore create schema

* tweak storage param for postgres 15
This commit is contained in:
Groovie | Mango 2024-02-24 18:29:52 +01:00 committed by GitHub
parent 50dadc0071
commit bab25959f6
No known key found for this signature in database
GPG Key ID: B5690EEEBB952194
7 changed files with 299 additions and 158 deletions

28
DBA.md Normal file
View File

@ -0,0 +1,28 @@
## Inspect page density and TOAST usage
Shows how many rows fit on pages and how TOAST is used.
The related tunings are:
* configure `toast_tuple_target`
* configure ```STORAGE PLAIN/MAIN/EXTENDED/EXTERNAL```
* order of columns in the table
```sql
SELECT
pgsut.schemaname as schema_name,
pgsut.relname as table_name,
pg_size_pretty(pg_relation_size(pg_class.oid)) main_size,
pg_size_pretty(pg_relation_size(reltoastrelid)) toast_size,
n_live_tup,
pg_relation_size(pg_class.oid)/(n_live_tup+n_dead_tup) main_avg_size,
pg_relation_size(reltoastrelid)/(n_live_tup+n_dead_tup) toast_avg_size,
(select option_value::int FROM pg_options_to_table(reloptions) WHERE option_name='toast_tuple_target') as toast_tuple_target
FROM pg_class
INNER JOIN pg_namespace ns on relnamespace = ns.oid
INNER JOIN pg_stat_user_tables pgsut ON pgsut.relid=pg_class.oid
WHERE (n_live_tup+n_dead_tup)>0
AND nspname='banking_stage_results_2'
ORDER BY 1,2
```

View File

@ -1,19 +1,23 @@
# TO INSTALL POSTGRES SCHEMA AND DATABASE
# BankingStage Sidecar
This is a sidecar application for the BankingStage project. It is responsible for importing data from the Solana blockchain into the PostgreSQL database.
Data is retrieved via Solana RPC and Geysers gRPC API.
sudo -u postgres psql postgres
###### in postgres
create data
create database mangolana;
grant all privileges on database mangolana to galactus;
## Database Configuration
### Database Roles
* `bankingstage_sidecar` - write access to the database for the sidecar importer
* `bankingstage_dashboard` - read-only access to the database for the dashboard web application
* `query_user` - group for read-only access to the database intended for human user interaction with database
```sql
CREATE USER some_user_in_group_query_user PASSWORD 'test';
GRANT query_user TO some_user_in_group_query_user;
```
psql -d mangolana < migration.sql
### Configure sidecar PostgreSQL connection
export PG_CONFIG="host=localhost dbname=the_banking_stage_db user=some_user_in_group_query_user password=test sslmode=disable"
export PG_CONFIG="host=localhost dbname=mangolana user=galactus password=test sslmode=disable"
### Database Schema
The database schema is defined in the [migration.sql](migration.sql) file.
For new database installations start with the [init-database.sql](init-database.sql) file.
Required is a PostgreSQL database (tested version 15).
### give rights to user
GRANT ALL PRIVILEGES ON DATABASE mangolana TO galactus;
GRANT ALL PRIVILEGES ON SCHEMA banking_stage_results TO galactus;
GRANT ALL PRIVILEGES ON ALL TABLES IN SCHEMA banking_stage_results TO galactus;
ALTER DEFAULT PRIVILEGES IN SCHEMA banking_stage_results GRANT ALL PRIVILEGES ON TABLES TO galactus;

View File

@ -0,0 +1,13 @@
app = "solana-bankingstage-geyser-sidecar-migrate-hetzner"
primary_region = "fra"
kill_signal = "SIGINT"
kill_timeout = "5s"
[env]
RUST_LOG = "info,grpc_banking_transactions_notifications=debug"
[metrics]
path = "/"
port = 9091

View File

@ -1,5 +1,6 @@
app = "solana-bankingstage-geyser-sidecar"
primary_region = "nrt"
# shared-cpu-2x@4096MB
primary_region = "fra"
kill_signal = "SIGINT"
kill_timeout = "5s"

27
init-database.sql Normal file
View File

@ -0,0 +1,27 @@
-- setup new postgresql database; tested with PostgreSQL 15
-- CREATE DATABASE the_banking_stage_db
-- run migration.sql
-- setup sidecar user
GRANT CONNECT ON DATABASE the_banking_stage_db TO bankingstage_sidecar;
ALTER USER bankingstage_sidecar CONNECTION LIMIT 10;
GRANT USAGE ON SCHEMA banking_stage_results_2 TO bankingstage_sidecar;
GRANT ALL PRIVILEGES ON ALL TABLES IN SCHEMA banking_stage_results_2 TO bankingstage_sidecar;
ALTER DEFAULT PRIVILEGES IN SCHEMA banking_stage_results_2 GRANT ALL PRIVILEGES ON TABLES TO bankingstage_sidecar;
GRANT USAGE ON ALL SEQUENCES IN SCHEMA banking_stage_results_2 TO bankingstage_sidecar;
ALTER DEFAULT PRIVILEGES IN SCHEMA banking_stage_results_2 GRANT USAGE ON SEQUENCES TO bankingstage_sidecar;
-- setup query_user
GRANT CONNECT ON DATABASE the_banking_stage_db TO query_user;
ALTER USER query_user CONNECTION LIMIT 5;
GRANT USAGE ON SCHEMA banking_stage_results_2 TO query_user;
GRANT SELECT ON ALL TABLES in SCHEMA banking_stage_results_2 TO query_user;
-- setup bankingstage_dashboard
GRANT CONNECT ON DATABASE the_banking_stage_db TO bankingstage_dashboard;
ALTER USER bankingstage_sidecar CONNECTION LIMIT 10;
GRANT USAGE ON SCHEMA banking_stage_results_2 TO bankingstage_dashboard;
GRANT SELECT ON ALL TABLES in SCHEMA banking_stage_results_2 TO bankingstage_dashboard;

View File

@ -1,145 +1,168 @@
-- for initial database setup start with init-database.sql
-- note "STORAGE" option in column definition requires PostgreSQL 16 or later
CREATE SCHEMA banking_stage_results_2;
CREATE TABLE banking_stage_results_2.transactions(
signature char(88) primary key,
transaction_id bigserial,
UNIQUE(transaction_id)
transaction_id bigserial PRIMARY KEY,
signature varchar(88) NOT NULL,
UNIQUE(signature)
);
ALTER TABLE banking_stage_results_2.transactions ALTER COLUMN signature SET STORAGE MAIN;
-- page layout: rows are small and must store in main; compression is okey
-- ALTER TABLE banking_stage_results_2.transactions SET (toast_tuple_target=4080);
CREATE TABLE banking_stage_results_2.transaction_infos (
transaction_id BIGINT PRIMARY KEY,
processed_slot BIGINT,
is_successful BOOL,
cu_requested BIGINT,
cu_consumed BIGINT,
prioritization_fees BIGINT,
supp_infos text
transaction_id BIGINT PRIMARY KEY,
processed_slot BIGINT NOT NULL,
is_successful BOOL NOT NULL,
cu_requested BIGINT NOT NULL,
cu_consumed BIGINT NOT NULL,
prioritization_fees BIGINT NOT NULL,
supp_infos text
);
-- page layout: move supp_infos to toast; everything else should stay on main
ALTER TABLE banking_stage_results_2.transaction_infos SET (toast_tuple_target=128);
ALTER TABLE banking_stage_results_2.transaction_infos ALTER COLUMN supp_infos SET STORAGE extended;
CREATE TABLE banking_stage_results_2.errors (
error_code int primary key,
error_text text
error_code int primary key,
error_text text NOT NULL
);
-- page layout: keep everything on main
ALTER TABLE banking_stage_results_2.errors ALTER COLUMN error_text SET STORAGE main;
CREATE TABLE banking_stage_results_2.transaction_slot (
transaction_id BIGINT,
slot BIGINT,
error_code INT,
count INT,
utc_timestamp TIMESTAMP NOT NULL,
PRIMARY KEY (transaction_id, slot, error_code)
transaction_id BIGINT,
slot BIGINT NOT NULL,
error_code INT NOT NULL,
count INT NOT NULL,
utc_timestamp TIMESTAMP NOT NULL,
PRIMARY KEY (transaction_id, slot, error_code)
);
-- page layout: keep everything on main (note: TIMESTAMP uses storage plain)
ALTER TABLE banking_stage_results_2.transaction_slot SET (toast_tuple_target=128);
CREATE INDEX idx_transaction_slot_timestamp ON banking_stage_results_2.transaction_slot(utc_timestamp);
CREATE INDEX idx_transaction_slot_slot ON banking_stage_results_2.transaction_slot(slot);
CREATE TABLE banking_stage_results_2.blocks (
slot BIGINT PRIMARY KEY,
block_hash char(44),
leader_identity char(44),
successful_transactions BIGINT,
processed_transactions BIGINT,
total_cu_used BIGINT,
total_cu_requested BIGINT,
supp_infos text
slot BIGINT PRIMARY KEY,
successful_transactions BIGINT NOT NULL,
processed_transactions BIGINT NOT NULL,
total_cu_used BIGINT NOT NULL,
total_cu_requested BIGINT NOT NULL,
block_hash varchar(44) NOT NULL,
leader_identity varchar(44) NOT NULL,
supp_infos text
);
CREATE TABLE banking_stage_results_2.accounts(
acc_id bigserial primary key,
account_key char(44),
UNIQUE (account_key)
);
CREATE TABLE banking_stage_results_2.accounts_map_transaction(
acc_id BIGINT,
transaction_id BIGINT,
is_writable BOOL,
is_signer BOOL,
is_atl BOOL,
PRIMARY KEY (transaction_id, acc_id)
);
CREATE INDEX accounts_map_transaction_acc_id ON banking_stage_results_2.accounts_map_transaction(acc_id);
CREATE INDEX accounts_map_transaction_transaction_id ON banking_stage_results_2.accounts_map_transaction(transaction_id);
-- page layout: blockhash is frequently used
ALTER TABLE banking_stage_results_2.blocks SET (toast_tuple_target=200);
ALTER TABLE banking_stage_results_2.blocks ALTER COLUMN block_hash SET STORAGE main;
CREATE INDEX idx_blocks_block_hash ON banking_stage_results_2.blocks(block_hash);
CREATE TABLE banking_stage_results_2.accounts_map_blocks (
acc_id BIGINT,
slot BIGINT,
is_write_locked BOOL,
total_cu_consumed BIGINT,
total_cu_requested BIGINT,
prioritization_fees_info text,
supp_infos text,
PRIMARY KEY (acc_id, slot, is_write_locked)
CREATE TABLE banking_stage_results_2.accounts(
acc_id bigserial PRIMARY KEY,
account_key varchar(44) NOT NULL,
UNIQUE (account_key)
);
-- page layout: rows are small and must store in main; compression is okey
ALTER TABLE banking_stage_results_2.accounts ALTER COLUMN account_key SET STORAGE main;
-- ALTER TABLE banking_stage_results_2.transactions SET (toast_tuple_target=4080);
CREATE TABLE banking_stage_results_2.accounts_map_transaction(
transaction_id BIGINT NOT NULL,
acc_id BIGINT NOT NULL,
is_writable BOOL NOT NULL,
is_signer BOOL NOT NULL,
is_atl BOOL NOT NULL,
PRIMARY KEY (transaction_id, acc_id)
);
-- page layout: very small rows, keep everything on main
ALTER TABLE banking_stage_results_2.accounts_map_transaction SET (toast_tuple_target=128);
CREATE TABLE banking_stage_results_2.accounts_map_blocks (
acc_id BIGINT NOT NULL,
slot BIGINT NOT NULL,
is_write_locked BOOL NOT NULL,
total_cu_consumed BIGINT NOT NULL,
total_cu_requested BIGINT NOT NULL,
prioritization_fees_info text NOT NULL,
supp_infos text,
PRIMARY KEY (acc_id, slot, is_write_locked)
);
-- page layout: move prioritization_fees_info and supp_infos to toast; everything else should stay on main
ALTER TABLE banking_stage_results_2.accounts_map_blocks SET (toast_tuple_target=128);
ALTER TABLE banking_stage_results_2.accounts_map_blocks ALTER COLUMN prioritization_fees_info SET STORAGE extended;
ALTER TABLE banking_stage_results_2.accounts_map_blocks ALTER COLUMN supp_infos SET STORAGE extended;
CREATE INDEX idx_accounts_map_blocks_slot ON banking_stage_results_2.accounts_map_blocks(slot);
insert into banking_stage_results_2.errors (error_text, error_code) VALUES
('AccountBorrowOutstanding', 0),
('AccountInUse', 1),
('AccountLoadedTwice', 2),
('AccountNotFound', 3),
('AddressLookupTableNotFound', 4),
('AlreadyProcessed', 5),
('BlockhashNotFound', 6),
('CallChainTooDeep', 7),
('ClusterMaintenance', 8),
('DuplicateInstruction', 9),
('InstructionError', 10),
('InsufficientFundsForFee', 11),
('InsufficientFundsForRent', 12),
('InvalidAccountForFee', 13),
('InvalidAccountIndex', 14),
('InvalidAddressLookupTableData', 15),
('InvalidAddressLookupTableIndex', 16),
('InvalidAddressLookupTableOwner', 17),
('InvalidLoadedAccountsDataSizeLimit', 18),
('InvalidProgramForExecution', 19),
('InvalidRentPayingAccount', 20),
('InvalidWritableAccount', 21),
('MaxLoadedAccountsDataSizeExceeded', 22),
('MissingSignatureForFee', 23),
('ProgramAccountNotFound', 24),
('ResanitizationNeeded', 25),
('SanitizeFailure', 26),
('SignatureFailure', 27),
('TooManyAccountLocks', 28),
('UnbalancedTransaction', 29),
('UnsupportedVersion', 30),
('WouldExceedAccountDataBlockLimit', 31),
('WouldExceedAccountDataTotalLimit', 32),
('WouldExceedMaxAccountCostLimit', 33),
('WouldExceedMaxBlockCostLimit', 34),
('WouldExceedMaxVoteCostLimit', 35);
CLUSTER banking_stage_results_2.blocks using blocks_pkey;
VACUUM FULL banking_stage_results_2.blocks;
-- optional
CLUSTER banking_stage_results_2.transaction_slot using idx_transaction_slot_timestamp;
VACUUM FULL banking_stage_results_2.transaction_slot;
CLUSTER banking_stage_results_2.accounts_map_transaction using accounts_map_transaction_pkey;
CLUSTER banking_stage_results_2.transactions using transactions_pkey;
CLUSTER banking_stage_results_2.accounts using accounts_pkey;
CREATE TABLE banking_stage_results_2.accounts_map_transaction_latest(
acc_id BIGINT PRIMARY KEY,
-- sorted: oldest to latest, max 1000
tx_ids BIGINT[]
CREATE UNLOGGED TABLE banking_stage_results_2.accounts_map_transaction_latest(
acc_id BIGINT PRIMARY KEY,
-- max 120 int8 ids (see LIMIT_LATEST_TXS_PER_ACCOUNT)
tx_ids BIGINT[] NOT NULL
);
-- page layout: tx_ids is the only relevant data must remain in main; tx_ids size is intentionally limited to fit a single page; compression is okey
-- do not limit tuple size, it is not relevant
ALTER TABLE banking_stage_results_2.accounts_map_transaction_latest SET (toast_tuple_target=4080);
ALTER TABLE banking_stage_results_2.accounts_map_transaction_latest ALTER COLUMN tx_ids SET STORAGE main;
INSERT INTO banking_stage_results_2.errors (error_text, error_code) VALUES
('AccountBorrowOutstanding', 0),
('AccountInUse', 1),
('AccountLoadedTwice', 2),
('AccountNotFound', 3),
('AddressLookupTableNotFound', 4),
('AlreadyProcessed', 5),
('BlockhashNotFound', 6),
('CallChainTooDeep', 7),
('ClusterMaintenance', 8),
('DuplicateInstruction', 9),
('InstructionError', 10),
('InsufficientFundsForFee', 11),
('InsufficientFundsForRent', 12),
('InvalidAccountForFee', 13),
('InvalidAccountIndex', 14),
('InvalidAddressLookupTableData', 15),
('InvalidAddressLookupTableIndex', 16),
('InvalidAddressLookupTableOwner', 17),
('InvalidLoadedAccountsDataSizeLimit', 18),
('InvalidProgramForExecution', 19),
('InvalidRentPayingAccount', 20),
('InvalidWritableAccount', 21),
('MaxLoadedAccountsDataSizeExceeded', 22),
('MissingSignatureForFee', 23),
('ProgramAccountNotFound', 24),
('ResanitizationNeeded', 25),
('SanitizeFailure', 26),
('SignatureFailure', 27),
('TooManyAccountLocks', 28),
('UnbalancedTransaction', 29),
('UnsupportedVersion', 30),
('WouldExceedAccountDataBlockLimit', 31),
('WouldExceedAccountDataTotalLimit', 32),
('WouldExceedMaxAccountCostLimit', 33),
('WouldExceedMaxBlockCostLimit', 34),
('WouldExceedMaxVoteCostLimit', 35);
CREATE OR REPLACE FUNCTION array_dedup_append(base bigint[], append bigint[], n_limit int)
RETURNS bigint[]
AS $$
DECLARE
tmplist bigint[];
el bigint;
len int;
tmplist bigint[];
el bigint;
len int;
BEGIN
tmplist := base;
FOREACH el IN ARRAY append LOOP
@ -151,3 +174,48 @@ BEGIN
RETURN tmplist[(len + 1 - n_limit):];
END
$$ LANGUAGE plpgsql IMMUTABLE CALLED ON NULL INPUT;
ALTER TABLE banking_stage_results_2.accounts
SET (
autovacuum_vacuum_scale_factor=0,
autovacuum_vacuum_threshold=100,
autovacuum_vacuum_insert_scale_factor=0,
autovacuum_vacuum_insert_threshold=100,
autovacuum_analyze_scale_factor=0,
autovacuum_analyze_threshold=100
);
ALTER TABLE banking_stage_results_2.transactions
SET (
autovacuum_vacuum_scale_factor=0,
autovacuum_vacuum_threshold=1000,
autovacuum_vacuum_insert_scale_factor=0,
autovacuum_vacuum_insert_threshold=1000,
autovacuum_analyze_scale_factor=0,
autovacuum_analyze_threshold=1000
);
ALTER TABLE banking_stage_results_2.accounts_map_transaction
SET (
autovacuum_vacuum_scale_factor=0,
autovacuum_vacuum_threshold=10000,
autovacuum_vacuum_insert_scale_factor=0,
autovacuum_vacuum_insert_threshold=10000,
autovacuum_analyze_scale_factor=0,
autovacuum_analyze_threshold=10000
);
ALTER TABLE banking_stage_results_2.accounts_map_transaction_latest
SET (
autovacuum_vacuum_scale_factor=0,
autovacuum_vacuum_threshold=100,
autovacuum_vacuum_insert_scale_factor=0,
autovacuum_vacuum_insert_threshold=100,
autovacuum_analyze_scale_factor=0,
autovacuum_analyze_threshold=100
);
ALTER TABLE banking_stage_results_2.accounts_map_transaction_latest SET (FILLFACTOR=90);
ALTER INDEX banking_stage_results_2.accounts_map_transaction_latest_pkey SET (FILLFACTOR=50);

View File

@ -200,7 +200,7 @@ impl PostgresSession {
format!(
r#"
CREATE TEMP TABLE {}(
signature char(88)
signature varchar(88) NOT NULL
);
"#,
temp_table
@ -237,7 +237,7 @@ impl PostgresSession {
INSERT INTO banking_stage_results_2.transactions(signature)
SELECT signature FROM {}
ORDER BY signature
ON CONFLICT DO NOTHING
ON CONFLICT(signature) DO NOTHING
"#,
temp_table
);
@ -264,7 +264,7 @@ impl PostgresSession {
.execute(
format!(
"CREATE TEMP TABLE {}(
key TEXT
account_key VARCHAR(44) NOT NULL
);",
temp_table
)
@ -276,7 +276,7 @@ impl PostgresSession {
let statement = format!(
r#"
COPY {}(
key
account_key
) FROM STDIN BINARY
"#,
temp_table
@ -300,7 +300,7 @@ impl PostgresSession {
INSERT INTO banking_stage_results_2.accounts(account_key)
SELECT key FROM {}
ORDER BY key
ON CONFLICT DO NOTHING
ON CONFLICT(account_key) DO NOTHING
"#,
temp_table
);
@ -326,11 +326,11 @@ impl PostgresSession {
.execute(
format!(
"CREATE TEMP TABLE {}(
sig char(88),
slot BIGINT,
error_code INT,
count INT,
utc_timestamp TIMESTAMP
sig varchar(88) NOT NULL,
slot BIGINT NOT NULL,
error_code INT NOT NULL,
count INT NOT NULL,
utc_timestamp TIMESTAMP NOT NULL
);",
temp_table
)
@ -420,11 +420,11 @@ impl PostgresSession {
.execute(
format!(
"CREATE TEMP TABLE {}(
account_key char(44),
signature char(88),
is_writable BOOL,
is_signer BOOL,
is_atl BOOL
account_key varchar(44) NOT NULL,
signature varchar(88) NOT NULL,
is_writable BOOL NOT NULL,
is_signer BOOL NOT NULL,
is_atl BOOL NOT NULL
);",
temp_table
)
@ -522,7 +522,7 @@ impl PostgresSession {
let started_at = Instant::now();
let num_rows = self.client.execute(statement.as_str(), &[]).await?;
debug!(
"merged new transactions into accounts_map_transaction_latest for {} accounts in {}ms",
"merged new transactions into accounts_map_transaction_latest temp table for {} accounts in {}ms",
num_rows,
started_at.elapsed().as_millis()
);
@ -559,12 +559,12 @@ impl PostgresSession {
.execute(
format!(
"CREATE TEMP TABLE {}(
signature char(88),
processed_slot BIGINT,
is_successful BOOL,
cu_requested BIGINT,
cu_consumed BIGINT,
prioritization_fees BIGINT,
signature varchar(88) NOT NULL,
processed_slot BIGINT NOT NULL,
is_successful BOOL NOT NULL,
cu_requested BIGINT NOT NULL,
cu_consumed BIGINT NOT NULL,
prioritization_fees BIGINT NOT NULL,
supp_infos text
)",
temp_table
@ -657,11 +657,11 @@ impl PostgresSession {
.execute(
format!(
"CREATE TEMP TABLE {}(
account_key char(44),
slot BIGINT,
is_write_locked BOOL,
total_cu_requested BIGINT,
total_cu_consumed BIGINT,
account_key varchar(44) NOT NULL,
slot BIGINT NOT NULL,
is_write_locked BOOL NOT NULL,
total_cu_requested BIGINT NOT NULL,
total_cu_consumed BIGINT NOT NULL,
prioritization_fees_info text
)",
temp_table
@ -787,12 +787,12 @@ impl PostgresSession {
let statement = r#"
INSERT INTO banking_stage_results_2.blocks (
slot,
block_hash,
leader_identity,
successful_transactions,
processed_transactions,
total_cu_used,
total_cu_requested,
block_hash,
leader_identity,
supp_infos
) VALUES ($1, $2, $3, $4, $5, $6, $7, $8)
ON CONFLICT DO NOTHING
@ -804,12 +804,12 @@ impl PostgresSession {
statement,
&[
&block_info.slot,
&block_info.block_hash,
&block_info.leader_identity.clone().unwrap_or_default(),
&block_info.successful_transactions,
&block_info.processed_transactions,
&block_info.total_cu_used,
&block_info.total_cu_requested,
&block_info.block_hash,
&block_info.leader_identity.clone().unwrap_or_default(),
&serde_json::to_string(&block_info.sup_info)?,
],
)