Use pg_ivm extension for incremental materialized view updates, bump to postgres 15.3
All checks were successful
continuous-integration/drone/push Build is passing

This commit is contained in:
DataHoarder 2023-05-29 15:58:34 +02:00
parent 6286a8ab24
commit f0d81343cc
Signed by: DataHoarder
SSH key fingerprint: SHA256:OLTRf6Fl87G52SiR7sWLGNzlJt4WOX+tfI2yxo0z7xk
4 changed files with 75 additions and 65 deletions

View file

@ -49,7 +49,9 @@ services:
ports:
- ${SITE_PORT}:80
db:
image: postgres:15.2
build:
context: ./docker/postgres
dockerfile: Dockerfile
restart: always
read_only: true
shm_size: 4gb

View file

@ -0,0 +1,12 @@
FROM postgres:15.3
RUN apt-get update \
&& apt-get install -y --no-install-recommends git ca-certificates make gcc postgresql-server-dev-$PG_MAJOR=$PG_VERSION \
&& rm -rf /var/lib/apt/lists/*
RUN git clone --branch v1.5.1 --depth 1 https://github.com/sraoss/pg_ivm.git /usr/src/pg_ivm \
&& cd /usr/src/pg_ivm \
&& make install \
&& cd / \
&& rm -rf /usr/src/pg_ivm

View file

@ -82,18 +82,27 @@ func OpenIndex(connStr string, consensus *sidechain.Consensus, difficultyByHeigh
}
defer tx.Rollback()
viewMatch := regexp.MustCompile("CREATE (MATERIALIZED |)VIEW ([^ \n\t]+?)(_v[0-9]+)? AS\n")
immv := regexp.MustCompile("SELECT (create_immv)\\('([^ \n\t']+?)(_v[0-9]+)?',")
for _, statement := range strings.Split(dbSchema, ";") {
if matches := viewMatch.FindStringSubmatch(statement); matches != nil {
var matches []string
if matches = viewMatch.FindStringSubmatch(statement); matches == nil {
matches = immv.FindStringSubmatch(statement)
}
if matches != nil {
isMaterialized := matches[1] == "MATERIALIZED "
isImmv := matches[1] == "create_immv"
viewName := matches[2]
fullViewName := viewName
//base view for materialized one
if len(matches[3]) != 0 {
fullViewName = viewName + matches[3]
}
index.views[viewName] = fullViewName
if row, err := tx.Query(fmt.Sprintf("SELECT relname, relkind FROM pg_class WHERE relname LIKE '%s%%';", matches[2])); err != nil {
if row, err := tx.Query(fmt.Sprintf("SELECT relname, relkind FROM pg_class WHERE relname LIKE '%s%%';", viewName)); err != nil {
return nil, err
} else {
var entries []struct{ n, kind string }
var exists bool
if err = func() error {
defer row.Close()
@ -102,22 +111,30 @@ func OpenIndex(connStr string, consensus *sidechain.Consensus, difficultyByHeigh
if err = row.Scan(&n, &kind); err != nil {
return err
}
if kind == "m" && fullViewName != n {
if _, err := tx.Exec(fmt.Sprintf("DROP MATERIALIZED VIEW %s;", n)); err != nil {
return err
}
} else if kind == "v" && fullViewName != n {
if _, err := tx.Exec(fmt.Sprintf("DROP VIEW %s;", n)); err != nil {
return err
}
} else if kind != "i" {
exists = true
}
entries = append(entries, struct{ n, kind string }{n: n, kind: kind})
}
return nil
return row.Err()
}(); err != nil {
return nil, err
}
for _, e := range entries {
if e.kind == "m" && fullViewName != e.n {
if _, err := tx.Exec(fmt.Sprintf("DROP MATERIALIZED VIEW %s CASCADE;", e.n)); err != nil {
return nil, err
}
} else if e.kind == "v" && fullViewName != e.n {
if _, err := tx.Exec(fmt.Sprintf("DROP VIEW %s CASCADE;", e.n)); err != nil {
return nil, err
}
} else if e.kind == "r" && fullViewName != e.n {
if _, err := tx.Exec(fmt.Sprintf("DROP TABLE %s CASCADE;", e.n)); err != nil {
return nil, err
}
} else if e.kind != "i" {
exists = true
}
}
if !exists {
if _, err := tx.Exec(statement); err != nil {
return nil, err
@ -128,6 +145,10 @@ func OpenIndex(connStr string, consensus *sidechain.Consensus, difficultyByHeigh
if _, err := tx.Exec(fmt.Sprintf("REFRESH MATERIALIZED VIEW %s;", fullViewName)); err != nil {
return nil, err
}
} else if isImmv {
if _, err := tx.Exec(fmt.Sprintf("SELECT refresh_immv('%s', true);", fullViewName)); err != nil {
return nil, err
}
}
continue
} else {
@ -707,15 +728,6 @@ func (i *Index) InsertOrUpdateMainBlock(b *MainBlock) error {
return err
}
// Refresh materialized views
if _, err := tx.Exec("DELETE FROM "+i.views["payouts"]+" WHERE main_id = $1;", oldBlock.Id[:]); err != nil {
return err
}
if _, err := tx.Exec("DELETE FROM "+i.views["found_main_blocks"]+" WHERE main_id = $1;", oldBlock.Id[:]); err != nil {
return err
}
if err = tx.Commit(); err != nil {
return err
}
@ -729,7 +741,7 @@ func (i *Index) InsertOrUpdateMainBlock(b *MainBlock) error {
return err
} else {
defer tx.Rollback()
if result, err := tx.Exec(
if _, err := tx.Exec(
"INSERT INTO main_blocks (id, height, timestamp, reward, coinbase_id, difficulty, metadata, side_template_id, coinbase_private_key) VALUES ($1, $2, $3, $4, $5, $6, $7::jsonb, $8, $9) ON CONFLICT (id) DO UPDATE SET metadata = $7, side_template_id = $8, coinbase_private_key = $9;",
b.Id[:],
b.Height,
@ -742,12 +754,6 @@ func (i *Index) InsertOrUpdateMainBlock(b *MainBlock) error {
&b.CoinbasePrivateKey,
); err != nil {
return err
} else if n, err := result.RowsAffected(); err != nil {
return err
} else if n > 0 {
if _, err := tx.Exec("REFRESH MATERIALIZED VIEW CONCURRENTLY " + i.views["found_main_blocks"] + ";"); err != nil {
return err
}
}
return tx.Commit()
@ -1173,9 +1179,8 @@ func (i *Index) InsertOrUpdateMainCoinbaseOutputs(outputs MainCoinbaseOutputs) e
return err
} else {
defer tx.Rollback()
inserted := 0
for _, o := range outputs {
if result, err := tx.Exec(
if _, err := tx.Exec(
"INSERT INTO main_coinbase_outputs (id, index, global_output_index, miner, value) VALUES ($1, $2, $3, $4, $5) ON CONFLICT DO NOTHING;",
o.Id[:],
o.Index,
@ -1184,15 +1189,6 @@ func (i *Index) InsertOrUpdateMainCoinbaseOutputs(outputs MainCoinbaseOutputs) e
o.Value,
); err != nil {
return err
} else if n, err := result.RowsAffected(); err != nil {
return err
} else if n > 0 {
inserted++
}
}
if inserted > 0 {
if _, err := tx.Exec("REFRESH MATERIALIZED VIEW CONCURRENTLY " + i.views["payouts"] + ";"); err != nil {
return err
}
}
return tx.Commit()

View file

@ -129,9 +129,10 @@ CREATE EXTENSION IF NOT EXISTS pg_stat_statements;
-- Views
CREATE EXTENSION IF NOT EXISTS pg_ivm;
CREATE MATERIALIZED VIEW found_main_blocks_v1 AS
SELECT
SELECT create_immv('found_main_blocks_v4', $$
SELECT
m.id AS main_id,
m.height AS main_height,
m.timestamp AS timestamp,
@ -150,19 +151,18 @@ CREATE MATERIALIZED VIEW found_main_blocks_v1 AS
s.difficulty AS side_difficulty,
s.cumulative_difficulty AS side_cumulative_difficulty,
s.inclusion AS side_inclusion
FROM
(SELECT * FROM main_blocks WHERE side_template_id IS NOT NULL) AS m
LEFT JOIN LATERAL
(SELECT * FROM side_blocks) AS s ON s.main_id = m.id
WITH NO DATA;
FROM
(SELECT * FROM main_blocks WHERE side_template_id IS NOT NULL) AS m
JOIN
(SELECT * FROM side_blocks) AS s ON s.main_id = m.id
$$);
CREATE UNIQUE INDEX IF NOT EXISTS found_main_blocks_main_id_idx ON found_main_blocks_v1 (main_id);
CREATE INDEX IF NOT EXISTS found_main_blocks_miner_idx ON found_main_blocks_v1 (miner);
CREATE INDEX IF NOT EXISTS found_main_blocks_side_height_idx ON found_main_blocks_v1 (side_height);
CREATE UNIQUE INDEX IF NOT EXISTS found_main_blocks_main_id_idx ON found_main_blocks_v4 (main_id);
CREATE INDEX IF NOT EXISTS found_main_blocks_miner_idx ON found_main_blocks_v4 (miner);
CREATE INDEX IF NOT EXISTS found_main_blocks_side_height_idx ON found_main_blocks_v4 (side_height);
CREATE MATERIALIZED VIEW payouts_v2 AS
SELECT
SELECT create_immv('payouts_v4', $$
SELECT
o.miner AS miner,
m.id AS main_id,
m.height AS main_height,
@ -176,17 +176,17 @@ CREATE MATERIALIZED VIEW payouts_v2 AS
o.index AS index,
o.global_output_index AS global_output_index,
s.including_height AS including_height
FROM
(SELECT id, value, index, global_output_index, miner FROM main_coinbase_outputs) AS o
LEFT JOIN LATERAL
FROM
(SELECT id, value, index, global_output_index, miner FROM main_coinbase_outputs) AS o
JOIN
(SELECT id, height, timestamp, side_template_id, coinbase_id, coinbase_private_key FROM main_blocks) AS m ON m.coinbase_id = o.id
LEFT JOIN LATERAL
JOIN
(SELECT template_id, main_id, side_height, uncle_of, GREATEST(0, GREATEST(effective_height, side_height) - window_depth) AS including_height FROM side_blocks) AS s ON s.main_id = m.id
WITH NO DATA;
$$);
CREATE UNIQUE INDEX IF NOT EXISTS found_main_blocks_global_output_index_idx ON payouts_v2 (global_output_index);
CREATE INDEX IF NOT EXISTS payouts_miner_idx ON payouts_v2 (miner);
CREATE INDEX IF NOT EXISTS payouts_main_id_idx ON payouts_v2 (main_id);
CREATE INDEX IF NOT EXISTS payouts_side_height_idx ON payouts_v2 (side_height);
CREATE INDEX IF NOT EXISTS payouts_main_height_idx ON payouts_v2 (main_height);
CREATE UNIQUE INDEX IF NOT EXISTS found_main_blocks_global_output_index_idx ON payouts_v4 (global_output_index);
CREATE INDEX IF NOT EXISTS payouts_miner_idx ON payouts_v4 (miner);
CREATE INDEX IF NOT EXISTS payouts_main_id_idx ON payouts_v4 (main_id);
CREATE INDEX IF NOT EXISTS payouts_side_height_idx ON payouts_v4 (side_height);
CREATE INDEX IF NOT EXISTS payouts_main_height_idx ON payouts_v4 (main_height);