Use indexed materialized views for found_main_blocks, payouts
All checks were successful
continuous-integration/drone/push Build is passing

This commit is contained in:
DataHoarder 2023-05-29 08:39:13 +02:00
parent fe11ac2513
commit 8774b1d70c
Signed by: DataHoarder
SSH key fingerprint: SHA256:OLTRf6Fl87G52SiR7sWLGNzlJt4WOX+tfI2yxo0z7xk
2 changed files with 112 additions and 21 deletions

View file

@ -19,6 +19,7 @@ import (
"golang.org/x/exp/slices"
"log"
"reflect"
"regexp"
"runtime/pprof"
"strings"
"sync"
@ -52,6 +53,8 @@ type Index struct {
minerLock sync.RWMutex
miner map[uint64]*Miner
}
views map[string]string
}
//go:embed schema.sql
@ -65,6 +68,7 @@ func OpenIndex(connStr string, consensus *sidechain.Consensus, difficultyByHeigh
getByTemplateId: getByTemplateId,
derivationCache: sidechain.NewDerivationLRUCache(),
blockCache: lru.New[types.Hash, *sidechain.PoolBlock](int(consensus.ChainWindowSize * 4)),
views: make(map[string]string),
}
if index.handle, err = sql.Open("postgres", connStr); err != nil {
return nil, err
@ -77,7 +81,61 @@ func OpenIndex(connStr string, consensus *sidechain.Consensus, difficultyByHeigh
return nil, err
}
defer tx.Rollback()
viewMatch := regexp.MustCompile("CREATE (MATERIALIZED |)VIEW ([^ \n\t]+?)(_v[0-9]+)? AS\n")
for _, statement := range strings.Split(dbSchema, ";") {
if matches := viewMatch.FindStringSubmatch(statement); matches != nil {
isMaterialized := matches[1] == "MATERIALIZED "
viewName := matches[2]
fullViewName := viewName
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 {
return nil, err
} else {
var exists bool
if err = func() error {
defer row.Close()
for row.Next() {
var n, kind string
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
}
}
return nil
}(); err != nil {
return nil, err
}
if !exists {
if _, err := tx.Exec(statement); err != nil {
return nil, err
}
//Do first refresh
if isMaterialized {
if _, err := tx.Exec(fmt.Sprintf("REFRESH MATERIALIZED VIEW %s;", fullViewName)); err != nil {
return nil, err
}
}
continue
} else {
continue
}
}
}
if _, err := tx.Exec(statement); err != nil {
return nil, err
}
@ -425,7 +483,7 @@ func (i *Index) GetShares(limit, minerId uint64, onlyBlocks bool, inclusion Bloc
func (i *Index) GetFoundBlocks(where string, limit uint64, params ...any) []*FoundBlock {
result := make([]*FoundBlock, 0, limit)
if err := i.Query(fmt.Sprintf("SELECT * FROM found_main_blocks %s ORDER BY main_height DESC LIMIT %d;", where, limit), func(row RowScanInterface) error {
if err := i.Query(fmt.Sprintf("SELECT * FROM "+i.views["found_main_blocks"]+" %s ORDER BY main_height DESC LIMIT %d;", where, limit), func(row RowScanInterface) error {
var d FoundBlock
if err := d.ScanFromRow(i, row); err != nil {
@ -649,6 +707,14 @@ func (i *Index) InsertOrUpdateMainBlock(b *MainBlock) error {
return err
}
if _, err := tx.Exec("REFRESH MATERIALIZED VIEW " + i.views["payouts"] + ";"); err != nil {
return err
}
if _, err := tx.Exec("REFRESH MATERIALIZED VIEW " + i.views["found_main_blocks"] + ";"); err != nil {
return err
}
if err = tx.Commit(); err != nil {
return err
}
@ -658,19 +724,30 @@ func (i *Index) InsertOrUpdateMainBlock(b *MainBlock) error {
metadataJson, _ := utils.MarshalJSON(b.Metadata)
return i.Query(
"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;",
nil,
b.Id[:],
b.Height,
b.Timestamp,
b.Reward,
b.CoinbaseId[:],
b.Difficulty,
metadataJson,
&b.SideTemplateId,
&b.CoinbasePrivateKey,
)
if tx, err := i.handle.BeginTx(context.Background(), nil); err != nil {
return err
} else {
defer tx.Rollback()
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,
b.Timestamp,
b.Reward,
b.CoinbaseId[:],
b.Difficulty,
metadataJson,
&b.SideTemplateId,
&b.CoinbasePrivateKey,
); err != nil {
return err
}
if _, err := tx.Exec("REFRESH MATERIALIZED VIEW " + i.views["found_main_blocks"] + ";"); err != nil {
return err
}
return tx.Commit()
}
}
func (i *Index) GetPayoutsByMinerId(minerId uint64, limit uint64) chan *Payout {
@ -689,11 +766,11 @@ func (i *Index) GetPayoutsByMinerId(minerId uint64, limit uint64) chan *Payout {
}
if limit == 0 {
if err := i.Query("SELECT * FROM payouts WHERE miner = $1 ORDER BY main_height DESC;", resultFunc, minerId); err != nil {
if err := i.Query("SELECT * FROM "+i.views["payouts"]+" WHERE miner = $1 ORDER BY main_height DESC;", resultFunc, minerId); err != nil {
return
}
} else {
if err := i.Query("SELECT * FROM payouts WHERE miner = $1 ORDER BY main_height DESC LIMIT $2;", resultFunc, minerId, limit); err != nil {
if err := i.Query("SELECT * FROM "+i.views["payouts"]+" WHERE miner = $1 ORDER BY main_height DESC LIMIT $2;", resultFunc, minerId, limit); err != nil {
return
}
}
@ -717,7 +794,7 @@ func (i *Index) GetPayoutsBySideBlock(b *SideBlock) chan *Payout {
return nil
}
if err := i.Query("SELECT * FROM payouts WHERE miner = $1 AND ((side_height >= $2 AND including_height <= $2) OR main_id = $3) ORDER BY main_height DESC;", resultFunc, b.Miner, b.EffectiveHeight, &b.MainId); err != nil {
if err := i.Query("SELECT * FROM "+i.views["payouts"]+" WHERE miner = $1 AND ((side_height >= $2 AND including_height <= $2) OR main_id = $3) ORDER BY main_height DESC;", resultFunc, b.Miner, b.EffectiveHeight, &b.MainId); err != nil {
return
}
}()
@ -1104,6 +1181,9 @@ func (i *Index) InsertOrUpdateMainCoinbaseOutputs(outputs MainCoinbaseOutputs) e
return err
}
}
if _, err := tx.Exec("REFRESH MATERIALIZED VIEW " + i.views["payouts"] + ";"); err != nil {
return err
}
return tx.Commit()
}
}

View file

@ -123,13 +123,14 @@ CREATE INDEX IF NOT EXISTS main_likely_sweep_transactions_miner_idx ON main_like
CREATE INDEX IF NOT EXISTS main_likely_sweep_transactions_spending_output_indexes_idx ON main_likely_sweep_transactions USING GIN (spending_output_indices);
CREATE INDEX IF NOT EXISTS main_likely_sweep_transactions_global_output_indexes_idx ON main_likely_sweep_transactions USING GIN (global_output_indices);
CREATE INDEX IF NOT EXISTS main_likely_sweep_transactions_timestamp_idx ON main_likely_sweep_transactions (timestamp);
CREATE EXTENSION IF NOT EXISTS pg_stat_statements;
-- Views
CREATE OR REPLACE VIEW found_main_blocks AS
CREATE MATERIALIZED VIEW found_main_blocks_v1 AS
SELECT
m.id AS main_id,
m.height AS main_height,
@ -152,10 +153,14 @@ CREATE OR REPLACE VIEW found_main_blocks AS
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;
(SELECT * FROM side_blocks) AS s ON s.main_id = m.id
WITH NO DATA;
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 OR REPLACE VIEW payouts AS
CREATE MATERIALIZED VIEW payouts_v2 AS
SELECT
o.miner AS miner,
m.id AS main_id,
@ -175,4 +180,10 @@ CREATE OR REPLACE VIEW payouts AS
LEFT JOIN LATERAL
(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
(SELECT template_id, main_id, side_height, uncle_of, (effective_height - window_depth) AS including_height FROM side_blocks) AS s ON s.main_id = m.id;
(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 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);