diff --git a/backend/src/api/database-migration.ts b/backend/src/api/database-migration.ts index 1d6f10a2c..1dc0b9704 100644 --- a/backend/src/api/database-migration.ts +++ b/backend/src/api/database-migration.ts @@ -4,7 +4,7 @@ import logger from '../logger'; import { Common } from './common'; class DatabaseMigration { - private static currentVersion = 39; + private static currentVersion = 40; private queryTimeout = 120000; private statisticsAddedIndexed = false; private uniqueLogs: string[] = []; @@ -342,6 +342,12 @@ class DatabaseMigration { await this.$executeQuery('ALTER TABLE `nodes` ADD alias_search TEXT NULL DEFAULT NULL AFTER `alias`'); await this.$executeQuery('ALTER TABLE nodes ADD FULLTEXT(alias_search)'); } + + if (databaseSchemaVersion < 40 && isBitcoin === true) { + await this.$executeQuery('ALTER TABLE `nodes` ADD capacity bigint(20) unsigned DEFAULT NULL'); + await this.$executeQuery('ALTER TABLE `nodes` ADD channels int(11) unsigned DEFAULT NULL'); + await this.$executeQuery('ALTER TABLE `nodes` ADD INDEX `capacity` (`capacity`);'); + } } /** diff --git a/backend/src/api/explorer/nodes.api.ts b/backend/src/api/explorer/nodes.api.ts index e4730b5e9..c49ed9ac5 100644 --- a/backend/src/api/explorer/nodes.api.ts +++ b/backend/src/api/explorer/nodes.api.ts @@ -115,17 +115,13 @@ class NodesApi { public async $getTopCapacityNodes(full: boolean): Promise { try { - let [rows]: any[] = await DB.query('SELECT UNIX_TIMESTAMP(MAX(added)) as maxAdded FROM node_stats'); - const latestDate = rows[0].maxAdded; - + let rows: any; let query: string; if (full === false) { query = ` SELECT nodes.public_key AS publicKey, IF(nodes.alias = '', SUBSTRING(nodes.public_key, 1, 20), alias) as alias, - node_stats.capacity - FROM node_stats - JOIN nodes ON nodes.public_key = node_stats.public_key - WHERE added = FROM_UNIXTIME(${latestDate}) + nodes.capacity + FROM nodes ORDER BY capacity DESC LIMIT 100 `; @@ -133,16 +129,14 @@ class NodesApi { [rows] = await DB.query(query); } else { query = ` - SELECT node_stats.public_key AS publicKey, IF(nodes.alias = '', SUBSTRING(node_stats.public_key, 1, 20), alias) as alias, - CAST(COALESCE(node_stats.capacity, 0) as INT) as capacity, - CAST(COALESCE(node_stats.channels, 0) as INT) as channels, + SELECT nodes.public_key AS publicKey, IF(nodes.alias = '', SUBSTRING(nodes.public_key, 1, 20), alias) as alias, + CAST(COALESCE(nodes.capacity, 0) as INT) as capacity, + CAST(COALESCE(nodes.channels, 0) as INT) as channels, UNIX_TIMESTAMP(nodes.first_seen) as firstSeen, UNIX_TIMESTAMP(nodes.updated_at) as updatedAt, geo_names_city.names as city, geo_names_country.names as country - FROM node_stats - RIGHT JOIN nodes ON nodes.public_key = node_stats.public_key + FROM nodes LEFT JOIN geo_names geo_names_country ON geo_names_country.id = nodes.country_id AND geo_names_country.type = 'country' LEFT JOIN geo_names geo_names_city ON geo_names_city.id = nodes.city_id AND geo_names_city.type = 'city' - WHERE added = FROM_UNIXTIME(${latestDate}) ORDER BY capacity DESC LIMIT 100 `; @@ -163,17 +157,13 @@ class NodesApi { public async $getTopChannelsNodes(full: boolean): Promise { try { - let [rows]: any[] = await DB.query('SELECT UNIX_TIMESTAMP(MAX(added)) as maxAdded FROM node_stats'); - const latestDate = rows[0].maxAdded; - + let rows: any; let query: string; if (full === false) { query = ` SELECT nodes.public_key as publicKey, IF(nodes.alias = '', SUBSTRING(nodes.public_key, 1, 20), alias) as alias, - node_stats.channels - FROM node_stats - JOIN nodes ON nodes.public_key = node_stats.public_key - WHERE added = FROM_UNIXTIME(${latestDate}) + nodes.channels + FROM nodes ORDER BY channels DESC LIMIT 100; `; @@ -181,16 +171,14 @@ class NodesApi { [rows] = await DB.query(query); } else { query = ` - SELECT node_stats.public_key AS publicKey, IF(nodes.alias = '', SUBSTRING(node_stats.public_key, 1, 20), alias) as alias, - CAST(COALESCE(node_stats.channels, 0) as INT) as channels, - CAST(COALESCE(node_stats.capacity, 0) as INT) as capacity, + SELECT nodes.public_key AS publicKey, IF(nodes.alias = '', SUBSTRING(nodes.public_key, 1, 20), alias) as alias, + CAST(COALESCE(nodes.channels, 0) as INT) as channels, + CAST(COALESCE(nodes.capacity, 0) as INT) as capacity, UNIX_TIMESTAMP(nodes.first_seen) as firstSeen, UNIX_TIMESTAMP(nodes.updated_at) as updatedAt, geo_names_city.names as city, geo_names_country.names as country - FROM node_stats - RIGHT JOIN nodes ON nodes.public_key = node_stats.public_key + FROM nodes LEFT JOIN geo_names geo_names_country ON geo_names_country.id = nodes.country_id AND geo_names_country.type = 'country' LEFT JOIN geo_names geo_names_city ON geo_names_city.id = nodes.city_id AND geo_names_city.type = 'city' - WHERE added = FROM_UNIXTIME(${latestDate}) ORDER BY channels DESC LIMIT 100 `; @@ -261,7 +249,7 @@ class NodesApi { try { const publicKeySearch = search.replace('%', '') + '%'; const aliasSearch = search.replace(/[-_.]/g, ' ').replace(/[^a-zA-Z0-9 ]/g, '').split(' ').map((search) => '+' + search + '*').join(' '); - const query = `SELECT nodes.public_key, nodes.alias, node_stats.capacity FROM nodes LEFT JOIN node_stats ON node_stats.public_key = nodes.public_key WHERE nodes.public_key LIKE ? OR MATCH nodes.alias_search AGAINST (? IN BOOLEAN MODE) GROUP BY nodes.public_key ORDER BY node_stats.capacity DESC LIMIT 10`; + const query = `SELECT public_key, alias, capacity, channels FROM nodes WHERE public_key LIKE ? OR MATCH alias_search AGAINST (? IN BOOLEAN MODE) ORDER BY capacity DESC LIMIT 10`; const [rows]: any = await DB.query(query, [publicKeySearch, aliasSearch]); return rows; } catch (e) { @@ -276,7 +264,7 @@ class NodesApi { // List all channels and the two linked ISP query = ` - SELECT short_id, capacity, + SELECT short_id, channels.capacity, channels.node1_public_key AS node1PublicKey, isp1.names AS isp1, isp1.id as isp1ID, channels.node2_public_key AS node2PublicKey, isp2.names AS isp2, isp2.id as isp2ID FROM channels @@ -391,17 +379,11 @@ class NodesApi { public async $getNodesPerCountry(countryId: string) { try { const query = ` - SELECT nodes.public_key, CAST(COALESCE(node_stats.capacity, 0) as INT) as capacity, CAST(COALESCE(node_stats.channels, 0) as INT) as channels, + SELECT nodes.public_key, CAST(COALESCE(nodes.capacity, 0) as INT) as capacity, CAST(COALESCE(nodes.channels, 0) as INT) as channels, nodes.alias, UNIX_TIMESTAMP(nodes.first_seen) as first_seen, UNIX_TIMESTAMP(nodes.updated_at) as updated_at, geo_names_city.names as city, geo_names_country.names as country, geo_names_iso.names as iso_code, geo_names_subdivision.names as subdivision - FROM node_stats - JOIN ( - SELECT public_key, MAX(added) as last_added - FROM node_stats - GROUP BY public_key - ) as b ON b.public_key = node_stats.public_key AND b.last_added = node_stats.added - RIGHT JOIN nodes ON nodes.public_key = node_stats.public_key + FROM nodes LEFT JOIN geo_names geo_names_country ON geo_names_country.id = nodes.country_id AND geo_names_country.type = 'country' LEFT JOIN geo_names geo_names_city ON geo_names_city.id = nodes.city_id AND geo_names_city.type = 'city' LEFT JOIN geo_names geo_names_iso ON geo_names_iso.id = nodes.country_id AND geo_names_iso.type = 'country_iso_code' @@ -426,17 +408,10 @@ class NodesApi { public async $getNodesPerISP(ISPId: string) { try { const query = ` - SELECT nodes.public_key, CAST(COALESCE(node_stats.capacity, 0) as INT) as capacity, CAST(COALESCE(node_stats.channels, 0) as INT) as channels, + SELECT nodes.public_key, CAST(COALESCE(nodes.capacity, 0) as INT) as capacity, CAST(COALESCE(nodes.channels, 0) as INT) as channels, nodes.alias, UNIX_TIMESTAMP(nodes.first_seen) as first_seen, UNIX_TIMESTAMP(nodes.updated_at) as updated_at, geo_names_city.names as city, geo_names_country.names as country, geo_names_iso.names as iso_code, geo_names_subdivision.names as subdivision - FROM node_stats - JOIN ( - SELECT public_key, MAX(added) as last_added - FROM node_stats - GROUP BY public_key - ) as b ON b.public_key = node_stats.public_key AND b.last_added = node_stats.added - RIGHT JOIN nodes ON nodes.public_key = node_stats.public_key LEFT JOIN geo_names geo_names_country ON geo_names_country.id = nodes.country_id AND geo_names_country.type = 'country' LEFT JOIN geo_names geo_names_city ON geo_names_city.id = nodes.city_id AND geo_names_city.type = 'city' LEFT JOIN geo_names geo_names_iso ON geo_names_iso.id = nodes.country_id AND geo_names_iso.type = 'country_iso_code' @@ -464,7 +439,6 @@ class NodesApi { FROM nodes JOIN geo_names ON geo_names.id = nodes.country_id AND geo_names.type = 'country' JOIN geo_names geo_names_iso ON geo_names_iso.id = nodes.country_id AND geo_names_iso.type = 'country_iso_code' - JOIN channels ON channels.node1_public_key = nodes.public_key OR channels.node2_public_key = nodes.public_key GROUP BY country_id ORDER BY COUNT(DISTINCT nodes.public_key) DESC `; diff --git a/backend/src/tasks/lightning/sync-tasks/stats-importer.ts b/backend/src/tasks/lightning/sync-tasks/stats-importer.ts index 30cfcc62b..7ac1c5885 100644 --- a/backend/src/tasks/lightning/sync-tasks/stats-importer.ts +++ b/backend/src/tasks/lightning/sync-tasks/stats-importer.ts @@ -279,6 +279,17 @@ class LightningStatsImporter { nodeStats[public_key].capacity, nodeStats[public_key].channels, ]); + + if (!isHistorical) { + await DB.query( + `UPDATE nodes SET capacity = ?, channels = ? WHERE public_key = ?`, + [ + nodeStats[public_key].capacity, + nodeStats[public_key].channels, + public_key, + ] + ); + } } return {