sqldb/sqlc: add graph channel schemas

In this commit, we define the SQL schemas for storing graph channel
data. This includes a new `channels` table and a new `channel_features`
table along with various indices.
This commit is contained in:
Elle Mouton
2025-05-24 14:20:28 +02:00
parent bff2f2440c
commit e5d099ef14
3 changed files with 151 additions and 2 deletions

View File

@ -4,10 +4,19 @@ DROP INDEX IF EXISTS node_extra_types_unique;
DROP INDEX IF EXISTS node_features_unique;
DROP INDEX IF EXISTS node_addresses_unique;
DROP INDEX IF EXISTS source_nodes_unique;
DROP INDEX IF EXISTS channels_node_id_1_idx;
DROP INDEX IF EXISTS channels_node_id_2_idx;
DROP INDEX IF EXISTS channels_unique;
DROP INDEX IF EXISTS channels_version_outpoint_idx;
DROP INDEX IF EXISTS channel_features_unique;
DROP INDEX IF EXISTS channel_extra_types_unique;
-- Drop tables in order of reverse dependencies.
DROP TABLE IF EXISTS source_nodes;
DROP TABLE IF EXISTS node_addresses;
DROP TABLE IF EXISTS node_features;
DROP TABLE IF EXISTS node_extra_types;
DROP TABLE IF EXISTS nodes;
DROP TABLE IF EXISTS nodes;
DROP TABLE IF EXISTS channels;
DROP TABLE IF EXISTS channel_features;
DROP TABLE IF EXISTS channel_extra_types;

View File

@ -94,4 +94,117 @@ CREATE TABLE IF NOT EXISTS source_nodes (
);
CREATE UNIQUE INDEX IF NOT EXISTS source_nodes_unique ON source_nodes (
node_id
);
);
/* ─────────────────────────────────────────────
channel data tables
─────────────────────────────────────────────
*/
-- channels stores all teh channels that we are aware of in the graph.
CREATE TABLE IF NOT EXISTS channels (
-- The db ID of the channel.
id INTEGER PRIMARY KEY,
-- The protocol version that this node was gossiped on.
version SMALLINT NOT NULL,
-- The channel id (short channel id) of the channel.
scid BLOB NOT NULL,
-- A reference to a node in the nodes table for the node_1 node in
-- the channel announcement.
node_id_1 BIGINT NOT NULL REFERENCES nodes(id) ON DELETE CASCADE,
-- A reference to a node in the nodes table for the node_2 node in
-- the channel announcement.
node_id_2 BIGINT NOT NULL REFERENCES nodes(id) ON DELETE CASCADE,
-- The outpoint of the funding transaction. We chose to store this
-- in a string format for the sake of readability and user queries on
-- outpoint.
outpoint TEXT NOT NULL,
-- The capacity of the channel in millisatoshis. This is nullable since
-- (for the v1 protocol at least), the capacity is not necessarily known as
-- it is not gossiped in the channel announcement.
capacity BIGINT,
-- bitcoin_key_1 is the public key owned by node_1 that is used to create
-- a funding transaction. It is nullable since future protocol version may
-- not make use of this field.
bitcoin_key_1 BLOB,
-- bitcoin_key_2 is the public key owned by node_2 that is used to create
-- the funding transaction. It is nullable since future protocol version may
-- not make use of this field.
bitcoin_key_2 BLOB,
-- node_1_signature is the signature of the serialised channel announcement
-- using the node_1 public key. It is nullable since future protocol
-- versions may not make use of this field _and_ because for this node's own
-- channels, the signature will only be known after the initial record
-- creation.
node_1_signature BLOB,
-- node_2_signature is the signature of the serialised channel announcement
-- using the node_2 public key. It is nullable since future protocol
-- versions may not make use of this field _and_ because for this node's own
-- channels, the signature will only be known after the initial record
-- creation.
node_2_signature BLOB,
-- bitcoin_1_signature is the signature of the serialised channel
-- announcement using bitcion_key_1. It is nullable since future protocol
-- versions may not make use of this field _and_ because for this node's
-- own channels, the signature will only be known after the initial record
-- creation.
bitcoin_1_signature BLOB,
-- bitcoin_2_signature is the signature of the serialised channel
-- announcement using bitcion_key_2. It is nullable since future protocol
-- versions may not make use of this field _and_ because for this node's
-- own channels, the signature will only be known after the initial record
-- creation.
bitcoin_2_signature BLOB
);
-- We'll want to lookup all the channels owned by a node, so we create
-- indexes on the node_id_1 and node_id_2 columns.
CREATE INDEX IF NOT EXISTS channels_node_id_1_idx ON channels(node_id_1);
CREATE INDEX IF NOT EXISTS channels_node_id_2_idx ON channels(node_id_2);
-- A channel (identified by a short channel id) can only have one active
-- channel announcement per protocol version. We also order the index by
-- scid in descending order so that we have an idea of the latest channel
-- announcement we know of.
CREATE UNIQUE INDEX IF NOT EXISTS channels_unique ON channels(version, scid DESC);
CREATE INDEX IF NOT EXISTS channels_version_outpoint_idx ON channels(version, outpoint);
-- channel_features contains the feature bits of a channel.
CREATE TABLE IF NOT EXISTS channel_features (
-- The channel id this feature belongs to.
channel_id BIGINT NOT NULL REFERENCES channels(id) ON DELETE CASCADE,
-- The feature bit value.
feature_bit INTEGER NOT NULL
);
CREATE UNIQUE INDEX IF NOT EXISTS channel_features_unique ON channel_features (
channel_id, feature_bit
);
-- channel_extra_types stores any extra TLV fields covered by a channels
-- announcement that we do not have an explicit column for in the channels
-- table.
CREATE TABLE IF NOT EXISTS channel_extra_types (
-- The channel id this TLV field belongs to.
channel_id BIGINT NOT NULL REFERENCES channels(id) ON DELETE CASCADE,
-- The Type field.
type BIGINT NOT NULL,
-- The value field.
value BLOB
);
CREATE UNIQUE INDEX IF NOT EXISTS channel_extra_types_unique ON channel_extra_types (
type, channel_id
);

View File

@ -28,6 +28,33 @@ type AmpSubInvoiceHtlc struct {
Preimage []byte
}
type Channel struct {
ID int64
Version int16
Scid []byte
NodeID1 int64
NodeID2 int64
Outpoint string
Capacity sql.NullInt64
BitcoinKey1 []byte
BitcoinKey2 []byte
Node1Signature []byte
Node2Signature []byte
Bitcoin1Signature []byte
Bitcoin2Signature []byte
}
type ChannelExtraType struct {
ChannelID int64
Type int64
Value []byte
}
type ChannelFeature struct {
ChannelID int64
FeatureBit int32
}
type Invoice struct {
ID int64
Hash []byte