You signed in with another tab or window. Reload to refresh your session.You signed out in another tab or window. Reload to refresh your session.You switched accounts on another tab or window. Reload to refresh your session.Dismiss alert
Instead of having a flat organization under the default `public` schema, we classify tables in schemas. There is roughly one schema per database type.
The new hierarchy is:
- `local`
- `channels`
- `htlc_infos`
- `pending_settlement_commands`
- `peers`
- `network`
- `nodes`
- `public_channels`
- `pruned_channels`
- `payments`
- `received`
- `sent`
- `audit`
- (all the audit db tables)
- `public`
- `lease`
- `versions`
Note in particular, the change in naming for local channels vs external channels:
- `local_channels` -> `local.channels`
- `channels` -> `network.public_channels`
The two internal tables `lease` and `versions` stay in the `public`
schema, because we have no meta way of migrating them.
@@ -62,32 +62,50 @@ class PgAuditDb(implicit ds: DataSource) extends AuditDb with Logging {
62
62
statement.executeUpdate("ALTER TABLE channel_errors ALTER COLUMN timestamp SET DATA TYPE TIMESTAMP WITH TIME ZONE USING timestamp with time zone 'epoch' + timestamp * interval '1 millisecond'")
63
63
}
64
64
65
+
defmigration67(statement: Statement):Unit= {
66
+
statement.executeUpdate("CREATE SCHEMA audit")
67
+
statement.executeUpdate("ALTER TABLE sent SET SCHEMA audit")
68
+
statement.executeUpdate("ALTER TABLE received SET SCHEMA audit")
69
+
statement.executeUpdate("ALTER TABLE relayed SET SCHEMA audit")
70
+
statement.executeUpdate("ALTER TABLE relayed_trampoline SET SCHEMA audit")
71
+
statement.executeUpdate("ALTER TABLE network_fees SET SCHEMA audit")
72
+
statement.executeUpdate("ALTER TABLE channel_events SET SCHEMA audit")
73
+
statement.executeUpdate("ALTER TABLE channel_errors SET SCHEMA audit")
74
+
}
75
+
65
76
getVersion(statement, DB_NAME) match {
66
77
caseNone=>
67
-
statement.executeUpdate("CREATE TABLE sent (amount_msat BIGINT NOT NULL, fees_msat BIGINT NOT NULL, recipient_amount_msat BIGINT NOT NULL, payment_id TEXT NOT NULL, parent_payment_id TEXT NOT NULL, payment_hash TEXT NOT NULL, payment_preimage TEXT NOT NULL, recipient_node_id TEXT NOT NULL, to_channel_id TEXT NOT NULL, timestamp TIMESTAMP WITH TIME ZONE NOT NULL)")
68
-
statement.executeUpdate("CREATE TABLE received (amount_msat BIGINT NOT NULL, payment_hash TEXT NOT NULL, from_channel_id TEXT NOT NULL, timestamp TIMESTAMP WITH TIME ZONE NOT NULL)")
69
-
statement.executeUpdate("CREATE TABLE relayed (payment_hash TEXT NOT NULL, amount_msat BIGINT NOT NULL, channel_id TEXT NOT NULL, direction TEXT NOT NULL, relay_type TEXT NOT NULL, timestamp TIMESTAMP WITH TIME ZONE NOT NULL)")
70
-
statement.executeUpdate("CREATE TABLE relayed_trampoline (payment_hash TEXT NOT NULL, amount_msat BIGINT NOT NULL, next_node_id TEXT NOT NULL, timestamp TIMESTAMP WITH TIME ZONE NOT NULL)")
71
-
statement.executeUpdate("CREATE TABLE network_fees (channel_id TEXT NOT NULL, node_id TEXT NOT NULL, tx_id TEXT NOT NULL, fee_sat BIGINT NOT NULL, tx_type TEXT NOT NULL, timestamp TIMESTAMP WITH TIME ZONE NOT NULL)")
72
-
statement.executeUpdate("CREATE TABLE channel_events (channel_id TEXT NOT NULL, node_id TEXT NOT NULL, capacity_sat BIGINT NOT NULL, is_funder BOOLEAN NOT NULL, is_private BOOLEAN NOT NULL, event TEXT NOT NULL, timestamp TIMESTAMP WITH TIME ZONE NOT NULL)")
73
-
statement.executeUpdate("CREATE TABLE channel_errors (channel_id TEXT NOT NULL, node_id TEXT NOT NULL, error_name TEXT NOT NULL, error_message TEXT NOT NULL, is_fatal BOOLEAN NOT NULL, timestamp TIMESTAMP WITH TIME ZONE NOT NULL)")
78
+
statement.executeUpdate("CREATE SCHEMA audit")
74
79
75
-
statement.executeUpdate("CREATE INDEX sent_timestamp_idx ON sent(timestamp)")
76
-
statement.executeUpdate("CREATE INDEX received_timestamp_idx ON received(timestamp)")
77
-
statement.executeUpdate("CREATE INDEX relayed_timestamp_idx ON relayed(timestamp)")
78
-
statement.executeUpdate("CREATE INDEX relayed_payment_hash_idx ON relayed(payment_hash)")
79
-
statement.executeUpdate("CREATE INDEX relayed_trampoline_timestamp_idx ON relayed_trampoline(timestamp)")
80
-
statement.executeUpdate("CREATE INDEX relayed_trampoline_payment_hash_idx ON relayed_trampoline(payment_hash)")
81
-
statement.executeUpdate("CREATE INDEX network_fees_timestamp_idx ON network_fees(timestamp)")
82
-
statement.executeUpdate("CREATE INDEX channel_events_timestamp_idx ON channel_events(timestamp)")
83
-
statement.executeUpdate("CREATE INDEX channel_errors_timestamp_idx ON channel_errors(timestamp)")
80
+
statement.executeUpdate("CREATE TABLE audit.sent (amount_msat BIGINT NOT NULL, fees_msat BIGINT NOT NULL, recipient_amount_msat BIGINT NOT NULL, payment_id TEXT NOT NULL, parent_payment_id TEXT NOT NULL, payment_hash TEXT NOT NULL, payment_preimage TEXT NOT NULL, recipient_node_id TEXT NOT NULL, to_channel_id TEXT NOT NULL, timestamp TIMESTAMP WITH TIME ZONE NOT NULL)")
81
+
statement.executeUpdate("CREATE TABLE audit.received (amount_msat BIGINT NOT NULL, payment_hash TEXT NOT NULL, from_channel_id TEXT NOT NULL, timestamp TIMESTAMP WITH TIME ZONE NOT NULL)")
82
+
statement.executeUpdate("CREATE TABLE audit.relayed (payment_hash TEXT NOT NULL, amount_msat BIGINT NOT NULL, channel_id TEXT NOT NULL, direction TEXT NOT NULL, relay_type TEXT NOT NULL, timestamp TIMESTAMP WITH TIME ZONE NOT NULL)")
83
+
statement.executeUpdate("CREATE TABLE audit.relayed_trampoline (payment_hash TEXT NOT NULL, amount_msat BIGINT NOT NULL, next_node_id TEXT NOT NULL, timestamp TIMESTAMP WITH TIME ZONE NOT NULL)")
84
+
statement.executeUpdate("CREATE TABLE audit.network_fees (channel_id TEXT NOT NULL, node_id TEXT NOT NULL, tx_id TEXT NOT NULL, fee_sat BIGINT NOT NULL, tx_type TEXT NOT NULL, timestamp TIMESTAMP WITH TIME ZONE NOT NULL)")
85
+
statement.executeUpdate("CREATE TABLE audit.channel_events (channel_id TEXT NOT NULL, node_id TEXT NOT NULL, capacity_sat BIGINT NOT NULL, is_funder BOOLEAN NOT NULL, is_private BOOLEAN NOT NULL, event TEXT NOT NULL, timestamp TIMESTAMP WITH TIME ZONE NOT NULL)")
86
+
87
+
statement.executeUpdate("CREATE TABLE audit.channel_errors (channel_id TEXT NOT NULL, node_id TEXT NOT NULL, error_name TEXT NOT NULL, error_message TEXT NOT NULL, is_fatal BOOLEAN NOT NULL, timestamp TIMESTAMP WITH TIME ZONE NOT NULL)")
88
+
statement.executeUpdate("CREATE INDEX sent_timestamp_idx ON audit.sent(timestamp)")
89
+
statement.executeUpdate("CREATE INDEX received_timestamp_idx ON audit.received(timestamp)")
90
+
statement.executeUpdate("CREATE INDEX relayed_timestamp_idx ON audit.relayed(timestamp)")
91
+
statement.executeUpdate("CREATE INDEX relayed_payment_hash_idx ON audit.relayed(payment_hash)")
92
+
statement.executeUpdate("CREATE INDEX relayed_trampoline_timestamp_idx ON audit.relayed_trampoline(timestamp)")
93
+
statement.executeUpdate("CREATE INDEX relayed_trampoline_payment_hash_idx ON audit.relayed_trampoline(payment_hash)")
94
+
statement.executeUpdate("CREATE INDEX network_fees_timestamp_idx ON audit.network_fees(timestamp)")
95
+
statement.executeUpdate("CREATE INDEX channel_events_timestamp_idx ON audit.channel_events(timestamp)")
96
+
statement.executeUpdate("CREATE INDEX channel_errors_timestamp_idx ON audit.channel_errors(timestamp)")
84
97
caseSome(v@4) =>
85
98
logger.warn(s"migrating db $DB_NAME, found version=$v current=$CURRENT_VERSION")
86
99
migration45(statement)
87
100
migration56(statement)
101
+
migration67(statement)
88
102
caseSome(v@5) =>
89
103
logger.warn(s"migrating db $DB_NAME, found version=$v current=$CURRENT_VERSION")
90
104
migration56(statement)
105
+
migration67(statement)
106
+
caseSome(v@6) =>
107
+
logger.warn(s"migrating db $DB_NAME, found version=$v current=$CURRENT_VERSION")
108
+
migration67(statement)
91
109
caseSome(CURRENT_VERSION) => () // table is up-to-date, nothing to do
92
110
caseSome(unknownVersion) =>thrownewRuntimeException(s"Unknown version of DB $DB_NAME found, version=$unknownVersion")
93
111
}
@@ -97,7 +115,7 @@ class PgAuditDb(implicit ds: DataSource) extends AuditDb with Logging {
0 commit comments