From ffbe4f6ffcd40c7de6ab4914def5e98d55a0483c Mon Sep 17 00:00:00 2001 From: Elle Mouton Date: Wed, 14 May 2025 16:23:01 +0200 Subject: [PATCH] sqldb: define schemas for all graph node tables In this commit, the various SQL schemas required to store graph node related data is defined. Specifically, the following tables are defined: - nodes - node_extra_types - node_features - node_addresses --- sqldb/migrations_dev.go | 8 +- sqldb/sqlc/migrations/000007_graph.down.sql | 11 +++ sqldb/sqlc/migrations/000007_graph.up.sql | 90 +++++++++++++++++++++ sqldb/sqlc/models.go | 28 +++++++ sqldb/sqlc/queries/graph.sql | 0 5 files changed, 136 insertions(+), 1 deletion(-) create mode 100644 sqldb/sqlc/migrations/000007_graph.down.sql create mode 100644 sqldb/sqlc/migrations/000007_graph.up.sql create mode 100644 sqldb/sqlc/queries/graph.sql diff --git a/sqldb/migrations_dev.go b/sqldb/migrations_dev.go index 61323dbff..112e68dd0 100644 --- a/sqldb/migrations_dev.go +++ b/sqldb/migrations_dev.go @@ -2,4 +2,10 @@ package sqldb -var migrationAdditions = []MigrationConfig{} +var migrationAdditions = []MigrationConfig{ + { + Name: "000007_graph", + Version: 8, + SchemaVersion: 7, + }, +} diff --git a/sqldb/sqlc/migrations/000007_graph.down.sql b/sqldb/sqlc/migrations/000007_graph.down.sql new file mode 100644 index 000000000..29f01750a --- /dev/null +++ b/sqldb/sqlc/migrations/000007_graph.down.sql @@ -0,0 +1,11 @@ +-- Drop indexes. +DROP INDEX IF EXISTS nodes_unique; +DROP INDEX IF EXISTS node_extra_types_unique; +DROP INDEX IF EXISTS node_features_unique; +DROP INDEX IF EXISTS node_addresses_unique; + +-- Drop tables in order of reverse dependencies. +DROP TABLE IF EXISTS node_addresses; +DROP TABLE IF EXISTS node_features; +DROP TABLE IF EXISTS node_extra_types; +DROP TABLE IF EXISTS nodes; \ No newline at end of file diff --git a/sqldb/sqlc/migrations/000007_graph.up.sql b/sqldb/sqlc/migrations/000007_graph.up.sql new file mode 100644 index 000000000..4e3ee6903 --- /dev/null +++ b/sqldb/sqlc/migrations/000007_graph.up.sql @@ -0,0 +1,90 @@ +/* ───────────────────────────────────────────── + node data tables + ───────────────────────────────────────────── +*/ + +-- nodes stores all the nodes that we are aware of in the LN graph. +CREATE TABLE IF NOT EXISTS nodes ( + -- The db ID of the node. This will only be used DB level + -- relations. + id INTEGER PRIMARY KEY, + + -- The protocol version that this node was gossiped on. + version SMALLINT NOT NULL, + + -- The public key (serialised compressed) of the node. + pub_key BLOB NOT NULL, + + -- The alias of the node. + alias TEXT, + + -- The unix timestamp of the last time the node was updated. + last_update BIGINT, + + -- The color of the node. + color VARCHAR, + + -- The signature of the node announcement. If this is null, then + -- the node announcement has not been received yet and this record + -- is a shell node. This can be the case if we receive a channel + -- announcement for a channel that is connected to a node that we + -- have not yet received a node announcement for. + signature BLOB +); + +-- A node (identified by a public key) can only have one active node +-- announcement per protocol. +CREATE UNIQUE INDEX IF NOT EXISTS nodes_unique ON nodes ( + pub_key, version +); + +-- node_extra_types stores any extra TLV fields covered by a node announcement that +-- we do not have an explicit column for in the nodes table. +CREATE TABLE IF NOT EXISTS node_extra_types ( + -- The node id this TLV field belongs to. + node_id BIGINT NOT NULL REFERENCES nodes(id) ON DELETE CASCADE, + + -- The Type field. + type BIGINT NOT NULL, + + -- The value field. + value BLOB +); +CREATE UNIQUE INDEX IF NOT EXISTS node_extra_types_unique ON node_extra_types ( + type, node_id +); + +-- node_features contains the feature bits of a node. +CREATE TABLE IF NOT EXISTS node_features ( + -- The node id this feature belongs to. + node_id BIGINT NOT NULL REFERENCES nodes(id) ON DELETE CASCADE, + + -- The feature bit value. + feature_bit INTEGER NOT NULL +); +CREATE UNIQUE INDEX IF NOT EXISTS node_features_unique ON node_features ( + node_id, feature_bit +); + +-- node_addresses contains the advertised addresses of nodes. +CREATE TABLE IF NOT EXISTS node_addresses ( + -- The node id this feature belongs to. + node_id BIGINT NOT NULL REFERENCES nodes(id) ON DELETE CASCADE, + + -- An enum that represents the type of address. This will + -- dictate how the address column should be parsed. + type SMALLINT NOT NULL, + + -- position is position of this address in the list of addresses + -- under the given type as it appeared in the node announcement. + -- We need to store this so that when we reconstruct the node + -- announcement, we preserve the original order of the addresses + -- so that the signature of the announcement remains valid. + position INTEGER NOT NULL, + + -- The advertised address of the node. + address TEXT NOT NULL +); +CREATE UNIQUE INDEX IF NOT EXISTS node_addresses_unique ON node_addresses ( + node_id, type, position +); \ No newline at end of file diff --git a/sqldb/sqlc/models.go b/sqldb/sqlc/models.go index b96cc0e94..ad256ca13 100644 --- a/sqldb/sqlc/models.go +++ b/sqldb/sqlc/models.go @@ -102,3 +102,31 @@ type MigrationTracker struct { Version int32 MigrationTime time.Time } + +type Node struct { + ID int64 + Version int16 + PubKey []byte + Alias sql.NullString + LastUpdate sql.NullInt64 + Color sql.NullString + Signature []byte +} + +type NodeAddress struct { + NodeID int64 + Type int16 + Position int32 + Address string +} + +type NodeExtraType struct { + NodeID int64 + Type int64 + Value []byte +} + +type NodeFeature struct { + NodeID int64 + FeatureBit int32 +} diff --git a/sqldb/sqlc/queries/graph.sql b/sqldb/sqlc/queries/graph.sql new file mode 100644 index 000000000..e69de29bb