sqldb+graph/db: prefix graph SQL objects with "graph_"

This makes it more clear what each table is for especially when viewed
with other invoice/payments tables.
This commit is contained in:
Elle Mouton
2025-07-15 17:44:23 +02:00
parent df6c02e3af
commit 74b70a5108
8 changed files with 615 additions and 608 deletions

View File

@@ -1,10 +1,10 @@
/* ─────────────────────────────────────────────
nodes table queries
────────────────────────────────────────────
graph_nodes table queries
───────────────────────────<EFBFBD><EFBFBD>─────────────────
*/
-- name: UpsertNode :one
INSERT INTO nodes (
INSERT INTO graph_nodes (
version, pub_key, alias, last_update, color, signature
) VALUES (
$1, $2, $3, $4, $5, $6
@@ -17,32 +17,32 @@ ON CONFLICT (pub_key, version)
last_update = EXCLUDED.last_update,
color = EXCLUDED.color,
signature = EXCLUDED.signature
WHERE nodes.last_update IS NULL
OR EXCLUDED.last_update > nodes.last_update
WHERE graph_nodes.last_update IS NULL
OR EXCLUDED.last_update > graph_nodes.last_update
RETURNING id;
-- name: GetNodeByPubKey :one
SELECT *
FROM nodes
FROM graph_nodes
WHERE pub_key = $1
AND version = $2;
-- name: GetNodeIDByPubKey :one
SELECT id
FROM nodes
FROM graph_nodes
WHERE pub_key = $1
AND version = $2;
-- name: ListNodesPaginated :many
SELECT *
FROM nodes
FROM graph_nodes
WHERE version = $1 AND id > $2
ORDER BY id
LIMIT $3;
-- name: ListNodeIDsAndPubKeys :many
SELECT id, pub_key
FROM nodes
FROM graph_nodes
WHERE version = $1 AND id > $2
ORDER BY id
LIMIT $3;
@@ -50,8 +50,8 @@ LIMIT $3;
-- name: IsPublicV1Node :one
SELECT EXISTS (
SELECT 1
FROM channels c
JOIN nodes n ON n.id = c.node_id_1 OR n.id = c.node_id_2
FROM graph_channels c
JOIN graph_nodes n ON n.id = c.node_id_1 OR n.id = c.node_id_2
-- NOTE: we hard-code the version here since the clauses
-- here that determine if a node is public is specific
-- to the V1 gossip protocol. In V1, a node is public
@@ -66,37 +66,37 @@ SELECT EXISTS (
);
-- name: DeleteUnconnectedNodes :many
DELETE FROM nodes
DELETE FROM graph_nodes
WHERE
-- Ignore any of our source nodes.
NOT EXISTS (
SELECT 1
FROM source_nodes sn
WHERE sn.node_id = nodes.id
FROM graph_source_nodes sn
WHERE sn.node_id = graph_nodes.id
)
-- Select all nodes that do not have any channels.
AND NOT EXISTS (
SELECT 1
FROM channels c
WHERE c.node_id_1 = nodes.id OR c.node_id_2 = nodes.id
FROM graph_channels c
WHERE c.node_id_1 = graph_nodes.id OR c.node_id_2 = graph_nodes.id
) RETURNING pub_key;
-- name: DeleteNodeByPubKey :execresult
DELETE FROM nodes
DELETE FROM graph_nodes
WHERE pub_key = $1
AND version = $2;
-- name: DeleteNode :exec
DELETE FROM nodes
DELETE FROM graph_nodes
WHERE id = $1;
/* ─────────────────────────────────────────────
node_features table queries
graph_node_features table queries
─────────────────────────────────────────────
*/
-- name: InsertNodeFeature :exec
INSERT INTO node_features (
INSERT INTO graph_node_features (
node_id, feature_bit
) VALUES (
$1, $2
@@ -104,28 +104,28 @@ INSERT INTO node_features (
-- name: GetNodeFeatures :many
SELECT *
FROM node_features
FROM graph_node_features
WHERE node_id = $1;
-- name: GetNodeFeaturesByPubKey :many
SELECT f.feature_bit
FROM nodes n
JOIN node_features f ON f.node_id = n.id
FROM graph_nodes n
JOIN graph_node_features f ON f.node_id = n.id
WHERE n.pub_key = $1
AND n.version = $2;
-- name: DeleteNodeFeature :exec
DELETE FROM node_features
DELETE FROM graph_node_features
WHERE node_id = $1
AND feature_bit = $2;
/* ─────────────────────────────────────────────
node_addresses table queries
────────────────────────────────────────────
graph_node_addresses table queries
───────────────────────────────────<EFBFBD><EFBFBD>─────────
*/
-- name: InsertNodeAddress :exec
INSERT INTO node_addresses (
INSERT INTO graph_node_addresses (
node_id,
type,
address,
@@ -136,28 +136,28 @@ INSERT INTO node_addresses (
-- name: GetNodeAddressesByPubKey :many
SELECT a.type, a.address
FROM nodes n
LEFT JOIN node_addresses a ON a.node_id = n.id
FROM graph_nodes n
LEFT JOIN graph_node_addresses a ON a.node_id = n.id
WHERE n.pub_key = $1 AND n.version = $2
ORDER BY a.type ASC, a.position ASC;
-- name: GetNodesByLastUpdateRange :many
SELECT *
FROM nodes
FROM graph_nodes
WHERE last_update >= @start_time
AND last_update < @end_time;
-- name: DeleteNodeAddresses :exec
DELETE FROM node_addresses
DELETE FROM graph_node_addresses
WHERE node_id = $1;
/* ─────────────────────────────────────────────
node_extra_types table queries
graph_node_extra_types table queries
─────────────────────────────────────────────
*/
-- name: UpsertNodeExtraType :exec
INSERT INTO node_extra_types (
INSERT INTO graph_node_extra_types (
node_id, type, value
)
VALUES ($1, $2, $3)
@@ -168,37 +168,37 @@ ON CONFLICT (type, node_id)
-- name: GetExtraNodeTypes :many
SELECT *
FROM node_extra_types
FROM graph_node_extra_types
WHERE node_id = $1;
-- name: DeleteExtraNodeType :exec
DELETE FROM node_extra_types
DELETE FROM graph_node_extra_types
WHERE node_id = $1
AND type = $2;
/* ─────────────────────────────────────────────
source_nodes table queries
graph_source_nodes table queries
─────────────────────────────────────────────
*/
-- name: AddSourceNode :exec
INSERT INTO source_nodes (node_id)
INSERT INTO graph_source_nodes (node_id)
VALUES ($1)
ON CONFLICT (node_id) DO NOTHING;
-- name: GetSourceNodesByVersion :many
SELECT sn.node_id, n.pub_key
FROM source_nodes sn
JOIN nodes n ON sn.node_id = n.id
FROM graph_source_nodes sn
JOIN graph_nodes n ON sn.node_id = n.id
WHERE n.version = $1;
/* ─────────────────────────────────────────────
channels table queries
graph_channels table queries
─────────────────────────────────────────────
*/
-- name: CreateChannel :one
INSERT INTO channels (
INSERT INTO graph_channels (
version, scid, node_id_1, node_id_2,
outpoint, capacity, bitcoin_key_1, bitcoin_key_2,
node_1_signature, node_2_signature, bitcoin_1_signature,
@@ -209,7 +209,7 @@ INSERT INTO channels (
RETURNING id;
-- name: AddV1ChannelProof :execresult
UPDATE channels
UPDATE graph_channels
SET node_1_signature = $2,
node_2_signature = $3,
bitcoin_1_signature = $4,
@@ -221,14 +221,14 @@ WHERE scid = $1
SELECT sqlc.embed(c),
n1.pub_key AS node1_pub_key,
n2.pub_key AS node2_pub_key
FROM channels c
JOIN nodes n1 ON c.node_id_1 = n1.id
JOIN nodes n2 ON c.node_id_2 = n2.id
FROM graph_channels c
JOIN graph_nodes n1 ON c.node_id_1 = n1.id
JOIN graph_nodes n2 ON c.node_id_2 = n2.id
WHERE scid >= @start_scid
AND scid < @end_scid;
-- name: GetChannelBySCID :one
SELECT * FROM channels
SELECT * FROM graph_channels
WHERE scid = $1 AND version = $2;
-- name: GetChannelByOutpoint :one
@@ -236,9 +236,9 @@ SELECT
sqlc.embed(c),
n1.pub_key AS node1_pubkey,
n2.pub_key AS node2_pubkey
FROM channels c
JOIN nodes n1 ON c.node_id_1 = n1.id
JOIN nodes n2 ON c.node_id_2 = n2.id
FROM graph_channels c
JOIN graph_nodes n1 ON c.node_id_1 = n1.id
JOIN graph_nodes n2 ON c.node_id_2 = n2.id
WHERE c.outpoint = $1;
-- name: GetChannelAndNodesBySCID :one
@@ -246,9 +246,9 @@ SELECT
c.*,
n1.pub_key AS node1_pub_key,
n2.pub_key AS node2_pub_key
FROM channels c
JOIN nodes n1 ON c.node_id_1 = n1.id
JOIN nodes n2 ON c.node_id_2 = n2.id
FROM graph_channels c
JOIN graph_nodes n1 ON c.node_id_1 = n1.id
JOIN graph_nodes n2 ON c.node_id_2 = n2.id
WHERE c.scid = $1
AND c.version = $2;
@@ -259,7 +259,7 @@ SELECT
cf.feature_bit AS feature_bit,
NULL AS extra_key,
NULL AS value
FROM channel_features cf
FROM graph_channel_features cf
WHERE cf.channel_id = $1
UNION ALL
@@ -270,11 +270,11 @@ SELECT
0 AS feature_bit,
cet.type AS extra_key,
cet.value AS value
FROM channel_extra_types cet
FROM graph_channel_extra_types cet
WHERE cet.channel_id = $1;
-- name: GetSCIDByOutpoint :one
SELECT scid from channels
SELECT scid from graph_channels
WHERE outpoint = $1 AND version = $2;
-- name: GetChannelsByPolicyLastUpdateRange :many
@@ -317,12 +317,12 @@ SELECT
cp2.channel_flags AS policy2_channel_flags,
cp2.signature AS policy2_signature
FROM channels c
JOIN nodes n1 ON c.node_id_1 = n1.id
JOIN nodes n2 ON c.node_id_2 = n2.id
LEFT JOIN channel_policies cp1
FROM graph_channels c
JOIN graph_nodes n1 ON c.node_id_1 = n1.id
JOIN graph_nodes n2 ON c.node_id_2 = n2.id
LEFT JOIN graph_channel_policies cp1
ON cp1.channel_id = c.id AND cp1.node_id = c.node_id_1 AND cp1.version = c.version
LEFT JOIN channel_policies cp2
LEFT JOIN graph_channel_policies cp2
ON cp2.channel_id = c.id AND cp2.node_id = c.node_id_2 AND cp2.version = c.version
WHERE c.version = @version
AND (
@@ -377,18 +377,18 @@ SELECT
cp2.message_flags AS policy_2_message_flags,
cp2.channel_flags AS policy_2_channel_flags,
cp2.signature AS policy_2_signature
FROM channels c
JOIN nodes n1 ON c.node_id_1 = n1.id
JOIN nodes n2 ON c.node_id_2 = n2.id
LEFT JOIN channel_policies cp1
FROM graph_channels c
JOIN graph_nodes n1 ON c.node_id_1 = n1.id
JOIN graph_nodes n2 ON c.node_id_2 = n2.id
LEFT JOIN graph_channel_policies cp1
ON cp1.channel_id = c.id AND cp1.node_id = c.node_id_1 AND cp1.version = c.version
LEFT JOIN channel_policies cp2
LEFT JOIN graph_channel_policies cp2
ON cp2.channel_id = c.id AND cp2.node_id = c.node_id_2 AND cp2.version = c.version
WHERE c.outpoint = $1 AND c.version = $2;
-- name: HighestSCID :one
SELECT scid
FROM channels
FROM graph_channels
WHERE version = $1
ORDER BY scid DESC
LIMIT 1;
@@ -435,26 +435,26 @@ SELECT sqlc.embed(c),
cp2.channel_flags AS policy2_channel_flags,
cp2.signature AS policy2_signature
FROM channels c
JOIN nodes n1 ON c.node_id_1 = n1.id
JOIN nodes n2 ON c.node_id_2 = n2.id
LEFT JOIN channel_policies cp1
FROM graph_channels c
JOIN graph_nodes n1 ON c.node_id_1 = n1.id
JOIN graph_nodes n2 ON c.node_id_2 = n2.id
LEFT JOIN graph_channel_policies cp1
ON cp1.channel_id = c.id AND cp1.node_id = c.node_id_1 AND cp1.version = c.version
LEFT JOIN channel_policies cp2
LEFT JOIN graph_channel_policies cp2
ON cp2.channel_id = c.id AND cp2.node_id = c.node_id_2 AND cp2.version = c.version
WHERE c.version = $1
AND (c.node_id_1 = $2 OR c.node_id_2 = $2);
-- name: GetPublicV1ChannelsBySCID :many
SELECT *
FROM channels
FROM graph_channels
WHERE node_1_signature IS NOT NULL
AND scid >= @start_scid
AND scid < @end_scid;
-- name: ListChannelsPaginated :many
SELECT id, bitcoin_key_1, bitcoin_key_2, outpoint
FROM channels c
FROM graph_channels c
WHERE c.version = $1 AND c.id > $2
ORDER BY c.id
LIMIT $3;
@@ -501,50 +501,50 @@ SELECT
cp2.channel_flags AS policy2_channel_flags,
cp2.signature AS policy_2_signature
FROM channels c
JOIN nodes n1 ON c.node_id_1 = n1.id
JOIN nodes n2 ON c.node_id_2 = n2.id
LEFT JOIN channel_policies cp1
FROM graph_channels c
JOIN graph_nodes n1 ON c.node_id_1 = n1.id
JOIN graph_nodes n2 ON c.node_id_2 = n2.id
LEFT JOIN graph_channel_policies cp1
ON cp1.channel_id = c.id AND cp1.node_id = c.node_id_1 AND cp1.version = c.version
LEFT JOIN channel_policies cp2
LEFT JOIN graph_channel_policies cp2
ON cp2.channel_id = c.id AND cp2.node_id = c.node_id_2 AND cp2.version = c.version
WHERE c.version = $1 AND c.id > $2
ORDER BY c.id
LIMIT $3;
-- name: DeleteChannel :exec
DELETE FROM channels WHERE id = $1;
DELETE FROM graph_channels WHERE id = $1;
/* ─────────────────────────────────────────────
channel_features table queries
graph_channel_features table queries
─────────────────────────────────────────────
*/
-- name: InsertChannelFeature :exec
INSERT INTO channel_features (
INSERT INTO graph_channel_features (
channel_id, feature_bit
) VALUES (
$1, $2
);
/* ─────────────────────────────────────────────
channel_extra_types table queries
graph_channel_extra_types table queries
─────────────────────────────────────────────
*/
-- name: CreateChannelExtraType :exec
INSERT INTO channel_extra_types (
INSERT INTO graph_channel_extra_types (
channel_id, type, value
)
VALUES ($1, $2, $3);
/* ─────────────────────────────────────────────
channel_policies table queries
graph_channel_policies table queries
─────────────────────────────────────────────
*/
-- name: UpsertEdgePolicy :one
INSERT INTO channel_policies (
INSERT INTO graph_channel_policies (
version, channel_id, node_id, timelock, fee_ppm,
base_fee_msat, min_htlc_msat, last_update, disabled,
max_htlc_msat, inbound_base_fee_msat,
@@ -569,12 +569,12 @@ ON CONFLICT (channel_id, node_id, version)
message_flags = EXCLUDED.message_flags,
channel_flags = EXCLUDED.channel_flags,
signature = EXCLUDED.signature
WHERE EXCLUDED.last_update > channel_policies.last_update
WHERE EXCLUDED.last_update > graph_channel_policies.last_update
RETURNING id;
-- name: GetChannelPolicyByChannelAndNode :one
SELECT *
FROM channel_policies
FROM graph_channel_policies
WHERE channel_id = $1
AND node_id = $2
AND version = $3;
@@ -619,23 +619,23 @@ SELECT
cp2.channel_flags AS policy_2_channel_flags,
cp2.signature AS policy2_signature
FROM channels c
JOIN nodes n1 ON c.node_id_1 = n1.id
JOIN nodes n2 ON c.node_id_2 = n2.id
LEFT JOIN channel_policies cp1
FROM graph_channels c
JOIN graph_nodes n1 ON c.node_id_1 = n1.id
JOIN graph_nodes n2 ON c.node_id_2 = n2.id
LEFT JOIN graph_channel_policies cp1
ON cp1.channel_id = c.id AND cp1.node_id = c.node_id_1 AND cp1.version = c.version
LEFT JOIN channel_policies cp2
LEFT JOIN graph_channel_policies cp2
ON cp2.channel_id = c.id AND cp2.node_id = c.node_id_2 AND cp2.version = c.version
WHERE c.scid = @scid
AND c.version = @version;
/* ─────────────────────────────────────────────
channel_policy_extra_types table queries
graph_channel_policy_extra_types table queries
─────────────────────────────────────────────
*/
-- name: InsertChanPolicyExtraType :exec
INSERT INTO channel_policy_extra_types (
INSERT INTO graph_channel_policy_extra_types (
channel_policy_id, type, value
)
VALUES ($1, $2, $3);
@@ -647,15 +647,15 @@ SELECT
cp.node_id,
cpet.type,
cpet.value
FROM channel_policies cp
JOIN channel_policy_extra_types cpet
FROM graph_channel_policies cp
JOIN graph_channel_policy_extra_types cpet
ON cp.id = cpet.channel_policy_id
WHERE cp.id = $1 OR cp.id = $2;
-- name: GetV1DisabledSCIDs :many
SELECT c.scid
FROM channels c
JOIN channel_policies cp ON cp.channel_id = c.id
FROM graph_channels c
JOIN graph_channel_policies cp ON cp.channel_id = c.id
-- NOTE: this is V1 specific since for V1, disabled is a
-- simple, single boolean. The proposed V2 policy
-- structure will have a more complex disabled bit vector
@@ -666,55 +666,55 @@ GROUP BY c.scid
HAVING COUNT(*) > 1;
-- name: DeleteChannelPolicyExtraTypes :exec
DELETE FROM channel_policy_extra_types
DELETE FROM graph_channel_policy_extra_types
WHERE channel_policy_id = $1;
/* ─────────────────────────────────────────────
zombie_channels table queries
graph_zombie_channels table queries
─────────────────────────────────────────────
*/
-- name: UpsertZombieChannel :exec
INSERT INTO zombie_channels (scid, version, node_key_1, node_key_2)
INSERT INTO graph_zombie_channels (scid, version, node_key_1, node_key_2)
VALUES ($1, $2, $3, $4)
ON CONFLICT (scid, version)
DO UPDATE SET
-- If a conflict exists for the SCID and version pair, then we
-- update the node keys.
node_key_1 = COALESCE(EXCLUDED.node_key_1, zombie_channels.node_key_1),
node_key_2 = COALESCE(EXCLUDED.node_key_2, zombie_channels.node_key_2);
node_key_1 = COALESCE(EXCLUDED.node_key_1, graph_zombie_channels.node_key_1),
node_key_2 = COALESCE(EXCLUDED.node_key_2, graph_zombie_channels.node_key_2);
-- name: DeleteZombieChannel :execresult
DELETE FROM zombie_channels
DELETE FROM graph_zombie_channels
WHERE scid = $1
AND version = $2;
-- name: CountZombieChannels :one
SELECT COUNT(*)
FROM zombie_channels
FROM graph_zombie_channels
WHERE version = $1;
-- name: GetZombieChannel :one
SELECT *
FROM zombie_channels
FROM graph_zombie_channels
WHERE scid = $1
AND version = $2;
-- name: IsZombieChannel :one
SELECT EXISTS (
SELECT 1
FROM zombie_channels
FROM graph_zombie_channels
WHERE scid = $1
AND version = $2
) AS is_zombie;
/* ────────────────────────────────────────────
prune_log table queries
/* ───────────────────────────<EFBFBD><EFBFBD><EFBFBD>─────────────────
graph_prune_log table queries
─────────────────────────────────────────────
*/
-- name: UpsertPruneLogEntry :exec
INSERT INTO prune_log (
INSERT INTO graph_prune_log (
block_height, block_hash
) VALUES (
$1, $2
@@ -724,33 +724,33 @@ ON CONFLICT(block_height) DO UPDATE SET
-- name: GetPruneTip :one
SELECT block_height, block_hash
FROM prune_log
FROM graph_prune_log
ORDER BY block_height DESC
LIMIT 1;
-- name: GetPruneHashByHeight :one
SELECT block_hash
FROM prune_log
FROM graph_prune_log
WHERE block_height = $1;
-- name: DeletePruneLogEntriesInRange :exec
DELETE FROM prune_log
DELETE FROM graph_prune_log
WHERE block_height >= @start_height
AND block_height <= @end_height;
/* ─────────────────────────────────────────────
closed_scid table queries
graph_closed_scid table queries
────────────────────────────────────────────-
*/
-- name: InsertClosedChannel :exec
INSERT INTO closed_scids (scid)
INSERT INTO graph_closed_scids (scid)
VALUES ($1)
ON CONFLICT (scid) DO NOTHING;
-- name: IsClosedChannel :one
SELECT EXISTS (
SELECT 1
FROM closed_scids
FROM graph_closed_scids
WHERE scid = $1
);