|
| 1 | +-------------------------------------------------------------------------------- |
| 2 | +-- SPO (Stake Pool Operator) tables for block explorer |
| 3 | +-------------------------------------------------------------------------------- |
| 4 | + |
| 5 | +-- Epochs table |
| 6 | +CREATE TABLE epochs ( |
| 7 | + epoch_no BIGINT PRIMARY KEY, |
| 8 | + starts_at TIMESTAMPTZ NOT NULL, |
| 9 | + ends_at TIMESTAMPTZ NOT NULL |
| 10 | +); |
| 11 | + |
| 12 | +-- Pool metadata cache |
| 13 | +CREATE TABLE pool_metadata_cache ( |
| 14 | + pool_id VARCHAR PRIMARY KEY, |
| 15 | + hex_id VARCHAR UNIQUE, |
| 16 | + name TEXT, |
| 17 | + ticker TEXT, |
| 18 | + homepage_url TEXT, |
| 19 | + updated_at TIMESTAMPTZ, |
| 20 | + url TEXT |
| 21 | +); |
| 22 | + |
| 23 | +-- SPO identity |
| 24 | +CREATE TABLE spo_identity ( |
| 25 | + spo_sk VARCHAR PRIMARY KEY, |
| 26 | + sidechain_pubkey VARCHAR UNIQUE, |
| 27 | + |
| 28 | + pool_id VARCHAR REFERENCES pool_metadata_cache(pool_id), |
| 29 | + mainchain_pubkey VARCHAR UNIQUE, |
| 30 | + aura_pubkey VARCHAR UNIQUE |
| 31 | +); |
| 32 | + |
| 33 | +-- Committee membership |
| 34 | +CREATE TABLE committee_membership ( |
| 35 | + spo_sk VARCHAR, |
| 36 | + sidechain_pubkey VARCHAR, |
| 37 | + |
| 38 | + epoch_no BIGINT NOT NULL, |
| 39 | + position INT NOT NULL, |
| 40 | + expected_slots INT NOT NULL, |
| 41 | + PRIMARY KEY (epoch_no, position) |
| 42 | +); |
| 43 | + |
| 44 | +-- SPO epoch performance |
| 45 | +CREATE TABLE spo_epoch_performance ( |
| 46 | + spo_sk VARCHAR REFERENCES spo_identity(spo_sk), |
| 47 | + identity_label VARCHAR, |
| 48 | + epoch_no BIGINT NOT NULL, |
| 49 | + expected_blocks INT NOT NULL, |
| 50 | + produced_blocks INT NOT NULL, |
| 51 | + PRIMARY KEY (epoch_no, spo_sk) |
| 52 | +); |
| 53 | + |
| 54 | +-- SPO history |
| 55 | +CREATE TABLE spo_history ( |
| 56 | + spo_hist_sk BIGSERIAL PRIMARY KEY, |
| 57 | + spo_sk VARCHAR REFERENCES spo_identity(spo_sk), |
| 58 | + epoch_no BIGINT NOT NULL, |
| 59 | + status TEXT NOT NULL, |
| 60 | + valid_from BIGINT NOT NULL, |
| 61 | + valid_to BIGINT NOT NULL, |
| 62 | + UNIQUE (spo_sk, epoch_no) |
| 63 | +); |
| 64 | + |
| 65 | +-- Update "updated_at" field each time the record is updated |
| 66 | +CREATE OR REPLACE FUNCTION set_updated_at_timestamp() |
| 67 | +RETURNS TRIGGER AS $$ |
| 68 | +BEGIN |
| 69 | + NEW.updated_at = NOW(); |
| 70 | + RETURN NEW; |
| 71 | +END; |
| 72 | +$$ LANGUAGE plpgsql; |
| 73 | + |
| 74 | +CREATE TRIGGER update_pool_metadata_cache_updated_at |
| 75 | +BEFORE UPDATE ON pool_metadata_cache |
| 76 | +FOR EACH ROW |
| 77 | +EXECUTE FUNCTION set_updated_at_timestamp(); |
| 78 | + |
| 79 | +-------------------------------------------------------------------------------- |
| 80 | +-- Stake snapshot per pool (latest values) |
| 81 | +-- Values are sourced from mainchain pool data (e.g., Blockfrost) |
| 82 | +-------------------------------------------------------------------------------- |
| 83 | + |
| 84 | +CREATE TABLE IF NOT EXISTS spo_stake_snapshot ( |
| 85 | + pool_id VARCHAR PRIMARY KEY REFERENCES pool_metadata_cache(pool_id) ON DELETE CASCADE, |
| 86 | + live_stake NUMERIC, -- current live stake (lovelace-like units) as big numeric |
| 87 | + active_stake NUMERIC, -- current active stake |
| 88 | + live_delegators INT, -- number of live delegators |
| 89 | + live_saturation DOUBLE PRECISION, -- saturation ratio (0..1+) |
| 90 | + declared_pledge NUMERIC, -- declared pledge |
| 91 | + live_pledge NUMERIC, -- current pledge |
| 92 | + updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW() |
| 93 | +); |
| 94 | + |
| 95 | +-------------------------------------------------------------------------------- |
| 96 | +-- Stake history table and refresh state cursor |
| 97 | +-------------------------------------------------------------------------------- |
| 98 | + |
| 99 | +CREATE TABLE IF NOT EXISTS spo_stake_history ( |
| 100 | + id BIGSERIAL PRIMARY KEY, |
| 101 | + pool_id VARCHAR NOT NULL REFERENCES pool_metadata_cache(pool_id) ON DELETE CASCADE, |
| 102 | + recorded_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), |
| 103 | + mainchain_epoch INTEGER, |
| 104 | + |
| 105 | + live_stake NUMERIC, |
| 106 | + active_stake NUMERIC, |
| 107 | + live_delegators INTEGER, |
| 108 | + live_saturation DOUBLE PRECISION, |
| 109 | + declared_pledge NUMERIC, |
| 110 | + live_pledge NUMERIC |
| 111 | +); |
| 112 | + |
| 113 | +-- Single-row state table to track paging cursor for stake refresh |
| 114 | +CREATE TABLE IF NOT EXISTS spo_stake_refresh_state ( |
| 115 | + id BOOLEAN PRIMARY KEY DEFAULT TRUE, |
| 116 | + last_pool_id VARCHAR, |
| 117 | + updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW() |
| 118 | +); |
| 119 | + |
| 120 | +INSERT INTO spo_stake_refresh_state (id) |
| 121 | +VALUES (TRUE) |
| 122 | +ON CONFLICT (id) DO NOTHING; |
| 123 | + |
| 124 | +-------------------------------------------------------------------------------- |
| 125 | +-- Indexes |
| 126 | +-------------------------------------------------------------------------------- |
| 127 | + |
| 128 | +CREATE INDEX IF NOT EXISTS spo_identity_pk ON spo_identity (pool_id, sidechain_pubkey, aura_pubkey); |
| 129 | +CREATE INDEX IF NOT EXISTS spo_history_epoch_no_idx ON spo_history (epoch_no); |
| 130 | +CREATE INDEX IF NOT EXISTS committee_membership_epoch_no_idx ON committee_membership (epoch_no); |
| 131 | +CREATE INDEX IF NOT EXISTS spo_epoch_performance_identity_pk ON spo_epoch_performance (epoch_no, identity_label); |
| 132 | +CREATE INDEX IF NOT EXISTS spo_epoch_performance_epoch_no_idx ON spo_epoch_performance (epoch_no); |
| 133 | +CREATE INDEX IF NOT EXISTS spo_stake_snapshot_updated_at_idx ON spo_stake_snapshot (updated_at DESC); |
| 134 | +CREATE INDEX IF NOT EXISTS spo_stake_snapshot_live_stake_idx ON spo_stake_snapshot ((COALESCE(live_stake, 0)) DESC); |
| 135 | +CREATE INDEX IF NOT EXISTS spo_stake_history_pool_time_idx ON spo_stake_history (pool_id, recorded_at DESC); |
| 136 | +CREATE INDEX IF NOT EXISTS spo_stake_history_epoch_idx ON spo_stake_history (mainchain_epoch); |
0 commit comments