Skip to content

Commit

Permalink
tapdb: universe query rewrites
Browse files Browse the repository at this point in the history
  • Loading branch information
jbrill committed Nov 6, 2024
1 parent 1188e50 commit 708cb3a
Show file tree
Hide file tree
Showing 5 changed files with 629 additions and 386 deletions.
Original file line number Diff line number Diff line change
@@ -1,21 +1,24 @@
-- Drop indices on universe_roots
DROP INDEX IF EXISTS idx_universe_roots_asset_group_proof;
DROP INDEX IF EXISTS idx_universe_roots_proof_type_issuance;

-- Drop in reverse order of dependencies
DROP INDEX IF EXISTS idx_multiverse_leaves_composite;
DROP INDEX IF EXISTS idx_federation_sync_composite;
DROP INDEX IF EXISTS idx_universe_events_root_type;
DROP INDEX IF EXISTS idx_universe_events_stats;
DROP INDEX IF EXISTS idx_mssmt_nodes_key_lookup;
DROP INDEX IF EXISTS idx_mssmt_nodes_namespace;
DROP INDEX IF EXISTS idx_universe_leaves_sort;
DROP INDEX IF EXISTS idx_universe_leaves_lookup;
DROP INDEX IF EXISTS idx_universe_roots_issuance;
DROP INDEX IF EXISTS idx_universe_roots_namespace;
-- Drop indices on universe_events
DROP INDEX IF EXISTS idx_universe_events_type_counts;
DROP INDEX IF EXISTS idx_universe_events_universe_root_id;
DROP INDEX IF EXISTS idx_universe_events_sync;

-- Update statistics
ANALYZE universe_roots;
ANALYZE universe_leaves;
ANALYZE mssmt_nodes;
ANALYZE universe_events;
ANALYZE federation_proof_sync_log;
ANALYZE multiverse_leaves;
ANALYZE multiverse_roots;
-- Drop indices on tables underlying key_group_info_view
DROP INDEX IF EXISTS idx_asset_group_witnesses_gen_asset_id;

-- Drop indices on mssmt_roots
DROP INDEX IF EXISTS idx_mssmt_roots_hash_namespace;

-- Drop indices on genesis_assets
DROP INDEX IF EXISTS idx_genesis_assets_asset_id;
DROP INDEX IF EXISTS idx_genesis_assets_asset_tag;
DROP INDEX IF EXISTS idx_genesis_assets_asset_type;

-- Drop indices on universe_leaves
DROP INDEX IF EXISTS idx_universe_leaves_universe_root_id;
DROP INDEX IF EXISTS idx_universe_leaves_asset_genesis_id;
DROP INDEX IF EXISTS idx_universe_leaves_leaf_node_key_namespace;
Original file line number Diff line number Diff line change
@@ -1,53 +1,43 @@
-- Core universe_roots indexes
CREATE INDEX IF NOT EXISTS idx_universe_roots_namespace
ON universe_roots(namespace_root, id, asset_id, group_key, proof_type);

CREATE INDEX IF NOT EXISTS idx_universe_roots_issuance
ON universe_roots(proof_type, group_key, id, asset_id, namespace_root);

-- Universe leaves optimization
CREATE INDEX IF NOT EXISTS idx_universe_leaves_lookup
ON universe_leaves(
leaf_node_namespace, minting_point, script_key_bytes,
id, leaf_node_key, universe_root_id, asset_genesis_id
);

CREATE INDEX IF NOT EXISTS idx_universe_leaves_sort
ON universe_leaves(leaf_node_namespace, id, minting_point, script_key_bytes);

-- MSSMT nodes optimization
CREATE INDEX IF NOT EXISTS idx_mssmt_nodes_namespace
ON mssmt_nodes(namespace, hash_key, key, value, sum);

CREATE INDEX IF NOT EXISTS idx_mssmt_nodes_key_lookup
ON mssmt_nodes(key, namespace, hash_key, value, sum);

-- Universe events optimization
CREATE INDEX IF NOT EXISTS idx_universe_events_stats
ON universe_events(event_type, event_timestamp);

CREATE INDEX IF NOT EXISTS idx_universe_events_root_type
ON universe_events(universe_root_id, event_type);

-- Federation sync log optimization
CREATE INDEX IF NOT EXISTS idx_federation_sync_composite
ON federation_proof_sync_log(
sync_direction, proof_leaf_id, universe_root_id, servers_id,
id, status, timestamp, attempt_counter
);

-- Multiverse optimization
CREATE INDEX IF NOT EXISTS idx_multiverse_leaves_composite
ON multiverse_leaves(
multiverse_root_id, leaf_node_namespace,
asset_id, group_key, leaf_node_key
);

-- Analyze existing tables
ANALYZE universe_roots;
ANALYZE universe_leaves;
ANALYZE mssmt_nodes;
ANALYZE universe_events;
ANALYZE federation_proof_sync_log;
ANALYZE multiverse_leaves;
ANALYZE multiverse_roots;
-- Composite index supporting joins and GROUP BY
CREATE INDEX IF NOT EXISTS idx_universe_roots_asset_group_proof
ON universe_roots (asset_id, group_key, proof_type);

-- Partial index for proof_type = 'issuance'
CREATE INDEX IF NOT EXISTS idx_universe_roots_proof_type_issuance
ON universe_roots (proof_type);

-- Composite index supporting event_type and universe_root_id
CREATE INDEX IF NOT EXISTS idx_universe_events_type_counts
ON universe_events (event_type, universe_root_id);

-- Separate index on universe_root_id
CREATE INDEX IF NOT EXISTS idx_universe_events_universe_root_id
ON universe_events (universe_root_id);

-- Partial index for event_type = 'SYNC'
CREATE INDEX IF NOT EXISTS idx_universe_events_sync
ON universe_events (event_type);

-- Indices on tables underlying key_group_info_view
CREATE INDEX IF NOT EXISTS idx_asset_group_witnesses_gen_asset_id
ON asset_group_witnesses (gen_asset_id);

-- Indices on mssmt_roots
CREATE INDEX IF NOT EXISTS idx_mssmt_roots_hash_namespace
ON mssmt_roots (root_hash, namespace);

-- Indices on genesis_assets
CREATE INDEX IF NOT EXISTS idx_genesis_assets_asset_id
ON genesis_assets (asset_id);
CREATE INDEX IF NOT EXISTS idx_genesis_assets_asset_tag
ON genesis_assets (asset_tag);
CREATE INDEX IF NOT EXISTS idx_genesis_assets_asset_type
ON genesis_assets (asset_type);

-- Indices on universe_leaves
CREATE INDEX IF NOT EXISTS idx_universe_leaves_universe_root_id
ON universe_leaves (universe_root_id);
CREATE INDEX IF NOT EXISTS idx_universe_leaves_asset_genesis_id
ON universe_leaves (asset_genesis_id);
CREATE INDEX IF NOT EXISTS idx_universe_leaves_leaf_node_key_namespace
ON universe_leaves (leaf_node_key, leaf_node_namespace);
113 changes: 46 additions & 67 deletions tapdb/sqlc/queries/universe.sql
Original file line number Diff line number Diff line change
Expand Up @@ -6,10 +6,10 @@ FROM universe_roots
JOIN mssmt_roots
ON universe_roots.namespace_root = mssmt_roots.namespace
JOIN mssmt_nodes
ON mssmt_nodes.hash_key = mssmt_roots.root_hash AND
mssmt_nodes.namespace = mssmt_roots.namespace
ON mssmt_nodes.hash_key = mssmt_roots.root_hash
AND mssmt_nodes.namespace = mssmt_roots.namespace
JOIN genesis_assets
ON genesis_assets.asset_id = universe_roots.asset_id
ON genesis_assets.asset_id = universe_roots.asset_id
WHERE mssmt_nodes.namespace = @namespace;

-- name: UpsertUniverseRoot :one
Expand All @@ -30,7 +30,7 @@ WITH root_id AS (
WHERE namespace_root = @namespace_root
)
DELETE FROM universe_events
WHERE universe_root_id = (SELECT id from root_id);
WHERE universe_root_id = (SELECT id FROM root_id);

-- name: DeleteUniverseRoot :exec
DELETE FROM universe_roots
Expand All @@ -54,25 +54,23 @@ DELETE FROM universe_leaves
WHERE leaf_node_namespace = @namespace;

-- name: QueryUniverseLeaves :many
SELECT leaves.script_key_bytes, gen.gen_asset_id, nodes.value genesis_proof,
nodes.sum sum_amt, gen.asset_id
FROM universe_leaves leaves
JOIN mssmt_nodes nodes
ON leaves.leaf_node_key = nodes.key AND
leaves.leaf_node_namespace = nodes.namespace
JOIN genesis_info_view gen
SELECT leaves.script_key_bytes, gen.gen_asset_id, nodes.value AS genesis_proof,
nodes.sum AS sum_amt, gen.asset_id
FROM universe_leaves AS leaves
JOIN mssmt_nodes AS nodes
ON leaves.leaf_node_key = nodes.key
AND leaves.leaf_node_namespace = nodes.namespace
JOIN genesis_info_view AS gen
ON leaves.asset_genesis_id = gen.gen_asset_id
WHERE leaves.leaf_node_namespace = @namespace
AND
(leaves.minting_point = sqlc.narg('minting_point_bytes') OR
sqlc.narg('minting_point_bytes') IS NULL)
AND
(leaves.script_key_bytes = sqlc.narg('script_key_bytes') OR
sqlc.narg('script_key_bytes') IS NULL);
AND (leaves.minting_point = sqlc.narg('minting_point_bytes') OR
sqlc.narg('minting_point_bytes') IS NULL)
AND (leaves.script_key_bytes = sqlc.narg('script_key_bytes') OR
sqlc.narg('script_key_bytes') IS NULL);

-- name: FetchUniverseKeys :many
SELECT leaves.minting_point, leaves.script_key_bytes
FROM universe_leaves leaves
FROM universe_leaves AS leaves
WHERE leaves.leaf_node_namespace = @namespace
ORDER BY
CASE WHEN sqlc.narg('sort_direction') = 0 THEN leaves.id END ASC,
Expand All @@ -84,14 +82,14 @@ SELECT * FROM universe_leaves;

-- name: UniverseRoots :many
SELECT universe_roots.asset_id, group_key, proof_type,
mssmt_roots.root_hash root_hash, mssmt_nodes.sum root_sum,
genesis_assets.asset_tag asset_name
mssmt_roots.root_hash AS root_hash, mssmt_nodes.sum AS root_sum,
genesis_assets.asset_tag AS asset_name
FROM universe_roots
JOIN mssmt_roots
ON universe_roots.namespace_root = mssmt_roots.namespace
JOIN mssmt_nodes
ON mssmt_nodes.hash_key = mssmt_roots.root_hash AND
mssmt_nodes.namespace = mssmt_roots.namespace
ON mssmt_nodes.hash_key = mssmt_roots.root_hash
AND mssmt_nodes.namespace = mssmt_roots.namespace
JOIN genesis_assets
ON genesis_assets.asset_id = universe_roots.asset_id
ORDER BY
Expand Down Expand Up @@ -329,8 +327,8 @@ SELECT
SUM(CASE WHEN event_type = 'SYNC' THEN 1 ELSE 0 END) AS sync_events,
SUM(CASE WHEN event_type = 'NEW_PROOF' THEN 1 ELSE 0 END) AS new_proof_events
FROM universe_events
WHERE event_type IN ('SYNC', 'NEW_PROOF') AND
event_timestamp >= @start_time AND event_timestamp <= @end_time
WHERE event_type IN ('SYNC', 'NEW_PROOF')
AND event_timestamp BETWEEN @start_time AND @end_time
GROUP BY day
ORDER BY day;

Expand Down Expand Up @@ -367,7 +365,7 @@ FROM federation_uni_sync_config
ORDER BY group_key NULLS LAST, asset_id NULLS LAST, proof_type;

-- name: UpsertFederationProofSyncLog :one
INSERT INTO federation_proof_sync_log as log (
INSERT INTO federation_proof_sync_log AS log (
status, timestamp, sync_direction, proof_leaf_id, universe_root_id,
servers_id
) VALUES (
Expand Down Expand Up @@ -401,66 +399,47 @@ DO UPDATE SET
timestamp = EXCLUDED.timestamp,
-- Increment the attempt counter.
attempt_counter = CASE
WHEN @bump_sync_attempt_counter = true THEN log.attempt_counter + 1
WHEN @bump_sync_attempt_counter = TRUE THEN log.attempt_counter + 1
ELSE log.attempt_counter
END
RETURNING id;

-- name: QueryFederationProofSyncLog :many
SELECT
log.id, status, timestamp, sync_direction, attempt_counter,

-- Select fields from the universe_servers table.
server.id as server_id,
server.id AS server_id,
server.server_host,

-- Select universe leaf related fields.
leaf.minting_point as leaf_minting_point_bytes,
leaf.script_key_bytes as leaf_script_key_bytes,
mssmt_node.value as leaf_genesis_proof,
genesis.gen_asset_id as leaf_gen_asset_id,
genesis.asset_id as leaf_asset_id,

leaf.minting_point AS leaf_minting_point_bytes,
leaf.script_key_bytes AS leaf_script_key_bytes,
mssmt_node.value AS leaf_genesis_proof,
genesis.gen_asset_id AS leaf_gen_asset_id,
genesis.asset_id AS leaf_asset_id,
-- Select fields from the universe_roots table.
root.asset_id as uni_asset_id,
root.group_key as uni_group_key,
root.proof_type as uni_proof_type

FROM federation_proof_sync_log as log

JOIN universe_leaves as leaf
root.asset_id AS uni_asset_id,
root.group_key AS uni_group_key,
root.proof_type AS uni_proof_type
FROM federation_proof_sync_log AS log
JOIN universe_leaves AS leaf
ON leaf.id = log.proof_leaf_id

-- Join on mssmt_nodes to get leaf related fields.
JOIN mssmt_nodes mssmt_node
ON leaf.leaf_node_key = mssmt_node.key AND
leaf.leaf_node_namespace = mssmt_node.namespace

JOIN mssmt_nodes AS mssmt_node
ON leaf.leaf_node_key = mssmt_node.key
AND leaf.leaf_node_namespace = mssmt_node.namespace
-- Join on genesis_info_view to get leaf related fields.
JOIN genesis_info_view genesis
JOIN genesis_info_view AS genesis
ON leaf.asset_genesis_id = genesis.gen_asset_id

JOIN universe_servers as server
JOIN universe_servers AS server
ON server.id = log.servers_id

JOIN universe_roots as root
JOIN universe_roots AS root
ON root.id = log.universe_root_id

WHERE (log.sync_direction = sqlc.narg('sync_direction')
OR sqlc.narg('sync_direction') IS NULL)
AND
(log.status = sqlc.narg('status') OR sqlc.narg('status') IS NULL)
AND

WHERE (log.sync_direction = sqlc.narg('sync_direction') OR sqlc.narg('sync_direction') IS NULL)
AND (log.status = sqlc.narg('status') OR sqlc.narg('status') IS NULL)
-- Universe leaves WHERE clauses.
(leaf.leaf_node_namespace = sqlc.narg('leaf_namespace')
OR sqlc.narg('leaf_namespace') IS NULL)
AND
(leaf.minting_point = sqlc.narg('leaf_minting_point_bytes')
OR sqlc.narg('leaf_minting_point_bytes') IS NULL)
AND
(leaf.script_key_bytes = sqlc.narg('leaf_script_key_bytes')
OR sqlc.narg('leaf_script_key_bytes') IS NULL);
AND (leaf.leaf_node_namespace = sqlc.narg('leaf_namespace') OR sqlc.narg('leaf_namespace') IS NULL)
AND (leaf.minting_point = sqlc.narg('leaf_minting_point_bytes') OR sqlc.narg('leaf_minting_point_bytes') IS NULL)
AND (leaf.script_key_bytes = sqlc.narg('leaf_script_key_bytes') OR sqlc.narg('leaf_script_key_bytes') IS NULL);

-- name: DeleteFederationProofSyncLog :exec
WITH selected_server_id AS (
Expand Down
Loading

0 comments on commit 708cb3a

Please sign in to comment.