From 237d88bbc56acad2a18566369a0dc0b1fab981f5 Mon Sep 17 00:00:00 2001 From: rdlrt <3169068+rdlrt@users.noreply.github.com> Date: Sun, 19 Nov 2023 15:33:58 +1100 Subject: [PATCH] Move dbscripts from guild-ops repo, add asset-txo-cache against whitelisted assets --- .../cron/jobs/active-stake-cache-update.sh | 0 .../cron/jobs/asset-info-cache-update.sh | 0 .../grest/cron/jobs/asset-registry-update.sh | 0 .../grest/cron/jobs/asset-txo-cache-update.sh | 12 ++ .../cron/jobs/epoch-info-cache-update.sh | 0 .../jobs/epoch-summary-corrections-update.sh | 0 .../cron/jobs/pool-history-cache-update.sh | 0 .../cron/jobs/populate-next-epoch-nonce.sh | 0 .../stake-distribution-new-accounts-update.sh | 0 .../cron/jobs/stake-distribution-update.sh | 0 files/grest/cron/jobs/stake-snapshot-cache.sh | 0 .../rpc/01_cached_tables/asset_txo_cache.sql | 64 +++++++ .../rpc/assets/asset_addresses_cached.sql | 40 ++++ .../rpc/db-scripts/asset_cache_control.sql | 18 ++ files/grest/rpc/db-scripts/basics.sql | 173 ++++++++++++++++++ files/grest/rpc/db-scripts/genesis_table.sql | 18 ++ files/grest/rpc/db-scripts/reset_grest.sql | 21 +++ 17 files changed, 346 insertions(+) mode change 100644 => 100755 files/grest/cron/jobs/active-stake-cache-update.sh mode change 100644 => 100755 files/grest/cron/jobs/asset-info-cache-update.sh mode change 100644 => 100755 files/grest/cron/jobs/asset-registry-update.sh create mode 100755 files/grest/cron/jobs/asset-txo-cache-update.sh mode change 100644 => 100755 files/grest/cron/jobs/epoch-info-cache-update.sh mode change 100644 => 100755 files/grest/cron/jobs/epoch-summary-corrections-update.sh mode change 100644 => 100755 files/grest/cron/jobs/pool-history-cache-update.sh mode change 100644 => 100755 files/grest/cron/jobs/populate-next-epoch-nonce.sh mode change 100644 => 100755 files/grest/cron/jobs/stake-distribution-new-accounts-update.sh mode change 100644 => 100755 files/grest/cron/jobs/stake-distribution-update.sh mode change 100644 => 100755 files/grest/cron/jobs/stake-snapshot-cache.sh create mode 100644 files/grest/rpc/01_cached_tables/asset_txo_cache.sql create mode 100644 files/grest/rpc/assets/asset_addresses_cached.sql create mode 100644 files/grest/rpc/db-scripts/asset_cache_control.sql create mode 100644 files/grest/rpc/db-scripts/basics.sql create mode 100644 files/grest/rpc/db-scripts/genesis_table.sql create mode 100644 files/grest/rpc/db-scripts/reset_grest.sql diff --git a/files/grest/cron/jobs/active-stake-cache-update.sh b/files/grest/cron/jobs/active-stake-cache-update.sh old mode 100644 new mode 100755 diff --git a/files/grest/cron/jobs/asset-info-cache-update.sh b/files/grest/cron/jobs/asset-info-cache-update.sh old mode 100644 new mode 100755 diff --git a/files/grest/cron/jobs/asset-registry-update.sh b/files/grest/cron/jobs/asset-registry-update.sh old mode 100644 new mode 100755 diff --git a/files/grest/cron/jobs/asset-txo-cache-update.sh b/files/grest/cron/jobs/asset-txo-cache-update.sh new file mode 100755 index 00000000..43ee7c74 --- /dev/null +++ b/files/grest/cron/jobs/asset-txo-cache-update.sh @@ -0,0 +1,12 @@ +#!/bin/bash +DB_NAME=cexplorer + +tip=$(psql ${DB_NAME} -qbt -c "SELECT EXTRACT(epoch FROM time)::integer FROM block ORDER BY id DESC LIMIT 1;" | xargs) + +if [[ $(( $(date +%s) - tip )) -gt 300 ]]; then + echo "$(date +%F_%H:%M:%S) Skipping as database has not received a new block in past 300 seconds!" && exit 1 +fi + +echo "$(date +%F_%H:%M:%S) Running asset txo cache update..." +psql ${DB_NAME} -qbt -c "SELECT grest.asset_txo_cache_update();" 1>/dev/null 2>&1 +echo "$(date +%F_%H:%M:%S) Job done!" diff --git a/files/grest/cron/jobs/epoch-info-cache-update.sh b/files/grest/cron/jobs/epoch-info-cache-update.sh old mode 100644 new mode 100755 diff --git a/files/grest/cron/jobs/epoch-summary-corrections-update.sh b/files/grest/cron/jobs/epoch-summary-corrections-update.sh old mode 100644 new mode 100755 diff --git a/files/grest/cron/jobs/pool-history-cache-update.sh b/files/grest/cron/jobs/pool-history-cache-update.sh old mode 100644 new mode 100755 diff --git a/files/grest/cron/jobs/populate-next-epoch-nonce.sh b/files/grest/cron/jobs/populate-next-epoch-nonce.sh old mode 100644 new mode 100755 diff --git a/files/grest/cron/jobs/stake-distribution-new-accounts-update.sh b/files/grest/cron/jobs/stake-distribution-new-accounts-update.sh old mode 100644 new mode 100755 diff --git a/files/grest/cron/jobs/stake-distribution-update.sh b/files/grest/cron/jobs/stake-distribution-update.sh old mode 100644 new mode 100755 diff --git a/files/grest/cron/jobs/stake-snapshot-cache.sh b/files/grest/cron/jobs/stake-snapshot-cache.sh old mode 100644 new mode 100755 diff --git a/files/grest/rpc/01_cached_tables/asset_txo_cache.sql b/files/grest/rpc/01_cached_tables/asset_txo_cache.sql new file mode 100644 index 00000000..e334f352 --- /dev/null +++ b/files/grest/rpc/01_cached_tables/asset_txo_cache.sql @@ -0,0 +1,64 @@ +CREATE OR REPLACE FUNCTION grest.asset_txo_cache_update() +RETURNS void +LANGUAGE plpgsql +AS $$ +BEGIN + IF ( + SELECT COUNT(pid) > 1 + FROM pg_stat_activity + WHERE state = 'active' + AND query ILIKE '%grest.asset_txo_cache_update%' + AND datname = (SELECT current_database()) + ) THEN + RAISE EXCEPTION 'Previous asset_txo_cache_update query still running but should have completed! Exiting...'; + END IF; + + WITH + ma_filtered AS + ( + (SELECT + mto.tx_out_id, + mto.quantity, + mto.ident + FROM grest.asset_cache_control AS acc + LEFT JOIN multi_asset AS ma ON ma.policy = acc.policy AND ma.name = acc.name + LEFT JOIN ma_tx_out AS mto ON mto.ident = ma.id + WHERE ma.id IN + ( + SELECT ma.id + FROM grest.asset_cache_control AS acc + LEFT JOIN multi_asset AS ma ON ma.policy = acc.policy AND acc.name = ma.name + LEFT JOIN grest.asset_tx_out_cache AS atoc ON ma.id = atoc.ma_id + WHERE atoc.ma_id IS NULL + ) + ) + UNION ALL + ( + SELECT + mto.tx_out_id, + mto.quantity, + mto.ident + FROM grest.asset_cache_control AS acc + LEFT JOIN multi_asset AS ma ON ma.policy = acc.policy AND ma.name = acc.name + LEFT JOIN ma_tx_out AS mto ON mto.ident = ma.id + WHERE mto.tx_out_id > (SELECT COALESCE(MAX(atoc.txo_id),0) FROM grest.asset_tx_out_cache AS atoc) + ) + ) + INSERT INTO grest.asset_tx_out_cache + SELECT + mf.ident, + mf.tx_out_id, + mf.quantity + FROM ma_filtered AS mf + LEFT JOIN tx_out AS txo ON mf.tx_out_id = txo.id + WHERE txo.consumed_by_tx_in_id IS NULL AND txo.id < (SELECT MAX(id) from tx_out) + ; + + DELETE FROM grest.asset_tx_out_cache WHERE txo_id IN + (SELECT atoc.txo_id + FROM grest.asset_tx_out_cache AS atoc + LEFT JOIN tx_out AS txo ON atoc.txo_id = txo.id + WHERE txo.consumed_by_tx_in_id IS NOT NULL + OR txo.id IS NULL); +END; +$$; diff --git a/files/grest/rpc/assets/asset_addresses_cached.sql b/files/grest/rpc/assets/asset_addresses_cached.sql new file mode 100644 index 00000000..b05fe4e0 --- /dev/null +++ b/files/grest/rpc/assets/asset_addresses_cached.sql @@ -0,0 +1,40 @@ +CREATE OR REPLACE FUNCTION grest.asset_addresses_cached(_asset_policy text, _asset_name text DEFAULT '') +RETURNS TABLE ( + payment_address varchar, + quantity text +) +LANGUAGE plpgsql +AS $$ +DECLARE + _asset_policy_decoded bytea; + _asset_name_decoded bytea; + _asset_id int; +BEGIN + SELECT DECODE(_asset_policy, 'hex') INTO _asset_policy_decoded; + SELECT DECODE(CASE + WHEN _asset_name IS NULL THEN '' + ELSE _asset_name + END, 'hex') INTO _asset_name_decoded; + SELECT id INTO _asset_id + FROM multi_asset AS ma + WHERE ma.policy = _asset_policy_decoded + AND ma.name = _asset_name_decoded; + + RETURN QUERY + SELECT + x.address, + SUM(x.quantity)::text + FROM + ( + SELECT + txo.address, + atoc.quantity + FROM grest.asset_tx_out_cache AS atoc + LEFT JOIN tx_out AS txo ON atoc.txo_id = txo.id + WHERE atoc.ma_id = _asset_id + ) AS x + GROUP BY x.address; +END; +$$; + +COMMENT ON FUNCTION grest.asset_addresses_cached IS 'Returns a list of addresses with quantity holding the specified asset (only valid for whitelisted cached assets)'; -- noqa: LT01 diff --git a/files/grest/rpc/db-scripts/asset_cache_control.sql b/files/grest/rpc/db-scripts/asset_cache_control.sql new file mode 100644 index 00000000..1d43cecb --- /dev/null +++ b/files/grest/rpc/db-scripts/asset_cache_control.sql @@ -0,0 +1,18 @@ +CREATE TABLE IF NOT EXISTS grest.asset_cache_control AS ( + SELECT policy, name FROM multi_asset LIMIT 0 +); + +CREATE TABLE IF NOT EXISTS grest.asset_tx_out_cache AS ( + SELECT id AS ma_id, id AS txo_id, quantity FROM ma_tx_out AS mto LIMIT 0 +); +CREATE INDEX IF NOT EXISTS idx_atoc_txoid ON grest.asset_tx_out_cache USING btree (txo_id); + +INSERT INTO grest.asset_cache_control VALUES (DECODE('13aa2accf2e1561723aa26871e071fdf32c867cff7e7d50ad470d62f','hex'),DECODE('4d494e53574150','hex')); +INSERT INTO grest.asset_cache_control VALUES (DECODE('92292852e3820cfbe99874b284fdf2befbddb38e070cf3512009a60a','hex'),DECODE('436f6c6f72506561726c','hex')); +INSERT INTO grest.asset_cache_control VALUES (DECODE('29d222ce763455e3d7a09a665ce554f00ac89d2e99a1a83d267170c6','hex'),DECODE('4d494e','hex')); +INSERT INTO grest.asset_cache_control VALUES (DECODE('de9b756719341e79785aa13c164e7fe68c189ed04d61c9876b2fe53f','hex'),DECODE('4d7565736c69537761705f414d4d','hex')); +INSERT INTO grest.asset_cache_control VALUES (DECODE('f43a62fdc3965df486de8a0d32fe800963589c41b38946602a0dc535','hex'),DECODE('41474958','hex')); +INSERT INTO grest.asset_cache_control VALUES (DECODE('a0028f350aaabe0545fdcb56b039bfb08e4bb4d8c4d7c3c7d481c235','hex'),DECODE('484f534b59','hex')); +INSERT INTO grest.asset_cache_control VALUES (DECODE('682fe60c9918842b3323c43b5144bc3d52a23bd2fb81345560d73f63','hex'),DECODE('4e45574d','hex')); +INSERT INTO grest.asset_cache_control VALUES (DECODE('af2e27f580f7f08e93190a81f72462f153026d06450924726645891b','hex'),DECODE('44524950','hex')); +INSERT INTO grest.asset_cache_control VALUES (DECODE('10a49b996e2402269af553a8a96fb8eb90d79e9eca79e2b4223057b6','hex'),DECODE('4745524f','hex')); \ No newline at end of file diff --git a/files/grest/rpc/db-scripts/basics.sql b/files/grest/rpc/db-scripts/basics.sql new file mode 100644 index 00000000..641b05d4 --- /dev/null +++ b/files/grest/rpc/db-scripts/basics.sql @@ -0,0 +1,173 @@ +-------------------------------------------------------------------------------- +-- Entry point for Koios node DB setup: +-- 1) grest schema that will hold all RPC functions/views and cached tables +-- 2) web_anon user +-- 3) grest.control_table +-- 4) grest.genesis +-- 5) drop existing functions +-- 6) helper functions +-- 7) optional db indexes on important public tables +-------------------------------------------------------------------------------- +-- GREST SCHEMA -- +CREATE SCHEMA IF NOT EXISTS grest; + +-- WEB_ANON USER -- +DO $$ +BEGIN + CREATE ROLE web_anon nologin; +EXCEPTION + WHEN DUPLICATE_OBJECT THEN + RAISE NOTICE 'web_anon exists, skipping...'; +END +$$; + +DO $$ +BEGIN + CREATE ROLE authenticator LOGIN; + EXECUTE FORMAT('GRANT CONNECT ON DATABASE %I to authenticator', current_database()); +EXCEPTION + WHEN DUPLICATE_OBJECT THEN + RAISE NOTICE 'authenticator exists, skipping...'; +END; +$$; + +GRANT USAGE ON SCHEMA public TO authenticator,web_anon; +GRANT USAGE ON SCHEMA grest TO authenticator,web_anon; +GRANT SELECT ON ALL TABLES IN SCHEMA public TO authenticator,web_anon; +GRANT SELECT ON ALL TABLES IN SCHEMA grest TO authenticator,web_anon; +GRANT web_anon TO authenticator; +ALTER ROLE authenticator SET statement_timeout = 125000; + +ALTER DEFAULT PRIVILEGES IN SCHEMA public GRANT +SELECT + ON TABLES TO web_anon,authenticator; + +ALTER DEFAULT PRIVILEGES IN SCHEMA grest GRANT +SELECT + ON TABLES TO web_anon,authenticator; + +ALTER ROLE web_anon SET search_path TO grest, public; +ALTER ROLE authenticator SET search_path TO grest, public; + +-- CONTROL TABLE -- +CREATE TABLE IF NOT EXISTS GREST.CONTROL_TABLE ( + key text PRIMARY KEY, + last_value text NOT NULL, + artifacts text +); + +-- GENESIS TABLE -- +DROP TABLE IF EXISTS grest.genesis; + +-- Data Types are intentionally kept varchar for single ID row to avoid future edge cases +CREATE TABLE grest.genesis ( + NETWORKMAGIC varchar, + NETWORKID varchar, + ACTIVESLOTCOEFF varchar, + UPDATEQUORUM varchar, + MAXLOVELACESUPPLY varchar, + EPOCHLENGTH varchar, + SYSTEMSTART varchar, + SLOTSPERKESPERIOD varchar, + SLOTLENGTH varchar, + MAXKESREVOLUTIONS varchar, + SECURITYPARAM varchar, + ALONZOGENESIS varchar +); + +-- DROP EXISTING FUNCTIONS +DO +$do$ +DECLARE + _sql text; +BEGIN + SELECT INTO _sql + string_agg( + format( + 'DROP %s %s CASCADE;', + CASE prokind + WHEN 'f' THEN 'FUNCTION' + WHEN 'a' THEN 'AGGREGATE' + WHEN 'p' THEN 'PROCEDURE' + WHEN 'w' THEN 'FUNCTION' -- window function (rarely applicable) + END, + oid::regprocedure + ), + E'\n' + ) + FROM + pg_proc + WHERE + pronamespace = 'grest'::regnamespace -- schema name here + AND prokind = ANY ('{f,a,p,w}'); -- optionally filter kinds + + IF _sql IS NOT NULL THEN + RAISE NOTICE '%', _sql; -- debug + EXECUTE _sql; + ELSE + RAISE NOTICE 'No fuctions found in schema %', quote_ident('grest'); + END IF; +END +$do$; + +-- HELPER FUNCTIONS -- +CREATE FUNCTION grest.get_query_pids_partial_match (_query text) + RETURNS TABLE ( + pid integer) + LANGUAGE plpgsql + AS $$ +BEGIN + RETURN QUERY + SELECT + pg_stat_activity.pid + FROM + pg_stat_activity + WHERE + query ILIKE '%' || _query || '%' + AND query NOT ILIKE '%grest.get_query_pids_partial_match%' + AND query NOT ILIKE '%grest.kill_queries_partial_match%' + AND datname = (SELECT current_database()); +END; +$$; + +CREATE PROCEDURE grest.kill_queries_partial_match (_query text) +LANGUAGE plpgsql +AS $$ +DECLARE + _pids integer[]; + _pid integer; +BEGIN + _pids := ARRAY ( + SELECT grest.get_query_pids_partial_match (_query) + ); + FOREACH _pid IN ARRAY _pids + LOOP + RAISE NOTICE 'Cancelling PID: %', _pid; + PERFORM PG_TERMINATE_BACKEND(_pid); + END LOOP; +END; +$$; + +CREATE FUNCTION grest.update_control_table (_key text, _last_value text, _artifacts text default null) + RETURNS void + LANGUAGE plpgsql + AS +$$ + BEGIN + INSERT INTO + GREST.CONTROL_TABLE (key, last_value, artifacts) + VALUES + (_key, _last_value, _artifacts) + ON CONFLICT ( + key + ) DO UPDATE + SET + last_value = _last_value, + artifacts = _artifacts; + END; +$$; + +-- Refresh asset token registry cache from github, to avoid stale deletes +DELETE FROM grest.control_table WHERE key='asset_registry_commit'; +-- DATABASE INDEXES -- +-- Empty diff --git a/files/grest/rpc/db-scripts/genesis_table.sql b/files/grest/rpc/db-scripts/genesis_table.sql new file mode 100644 index 00000000..7e4bb6df --- /dev/null +++ b/files/grest/rpc/db-scripts/genesis_table.sql @@ -0,0 +1,18 @@ +DROP TABLE IF EXISTS grest.genesis; + +-- Data Types are intentionally kept varchar for single ID row to avoid future edge cases +CREATE TABLE grest.genesis ( + NETWORKMAGIC varchar, + NETWORKID varchar, + ACTIVESLOTCOEFF varchar, + UPDATEQUORUM varchar, + MAXLOVELACESUPPLY varchar, + EPOCHLENGTH varchar, + SYSTEMSTART varchar, + SLOTSPERKESPERIOD varchar, + SLOTLENGTH varchar, + MAXKESREVOLUTIONS varchar, + SECURITYPARAM varchar, + ALONZOGENESIS varchar +); + diff --git a/files/grest/rpc/db-scripts/reset_grest.sql b/files/grest/rpc/db-scripts/reset_grest.sql new file mode 100644 index 00000000..a022ef6e --- /dev/null +++ b/files/grest/rpc/db-scripts/reset_grest.sql @@ -0,0 +1,21 @@ +-- Drop triggers first that depend on grest.functions() +SELECT + 'DROP TRIGGER ' || trigger_name || ' ON ' || event_object_table || ';' +FROM + information_schema.triggers +WHERE + trigger_schema = 'public'; + +-- Recreate grest schema +DROP SCHEMA IF EXISTS grest CASCADE; + +CREATE SCHEMA grest; + +GRANT USAGE ON SCHEMA grest TO authenticator,web_anon; + +GRANT SELECT ON ALL TABLES IN SCHEMA grest TO authenticator,web_anon; + +ALTER DEFAULT PRIVILEGES IN SCHEMA grest GRANT +SELECT + ON TABLES TO authenticator,web_anon; +