feat: MySQL db migration

Create database schema migration for this app that run when the `serve`
command is executed.
This commit is contained in:
ditatompel 2024-05-12 04:19:40 +07:00
parent bd37f17072
commit d3113bf598
No known key found for this signature in database
GPG key ID: 31D3D06D77950979
7 changed files with 194 additions and 166 deletions

View file

@ -11,11 +11,10 @@ Source code of [https://xmr.ditatompel.com](https://xmr.ditatompel.com).
### For initial server setup:
1. Create database structure and import `tbl_cron` data from [./tools/resources/database](./tools/resources/database).
2. Download [GeoIP Database](https://dev.maxmind.com/geoip/geoip2/geolite2/) and place it to `./assets/geoip`. (see [./internal/repo/geoip.go](./internal/repo/geoip.go)).
3. Copy `.env.example` to `.env` and edit it to match with server environment.
4. Build the binary with `make build`.
5. Run the service with `./bin/xmr-nodes-static-linux-<YOUR_CPU_ARCH> serve`.
1. Download [GeoIP Database](https://dev.maxmind.com/geoip/geoip2/geolite2/) and place it to `./assets/geoip`. (see [./internal/repo/geoip.go](./internal/repo/geoip.go)).
2. Copy `.env.example` to `.env` and edit it to match with server environment.
3. Build the binary with `make build`.
4. Run the service with `./bin/xmr-nodes-static-linux-<YOUR_CPU_ARCH> serve`.
To create admin user (for creating prober API key from Web-UI, execute `./bin/xmr-nodes-static-linux-<YOUR_CPU_ARCH> admin create`).

View file

@ -61,7 +61,9 @@ This command only available during migration process and will be removed in futu
action := newImport(database.GetDB())
for _, node := range response.Data {
action.processData(node)
if err := action.processData(node); err != nil {
fmt.Println(err)
}
}
fmt.Println("Total Source Data: ", len(response.Data))

View file

@ -40,6 +40,11 @@ func serve() {
panic(err)
}
// run db migrations
if err := database.MigrateDb(database.GetDB()); err != nil {
panic(err)
}
// Define Fiber config & app.
app := fiber.New(fiberConfig())

182
internal/database/schema.go Normal file
View file

@ -0,0 +1,182 @@
package database
import (
"fmt"
)
type migrateFn func(*DB) error
var dbMigrate = [...]migrateFn{v1}
func MigrateDb(db *DB) error {
version := getSchemaVersion(db)
if version < 0 {
return fmt.Errorf("can't get database schema version")
} else if version == 0 {
fmt.Println("No database schema version found, creating schema version 1")
} else {
fmt.Println("Database schema version:", version)
}
for ; version < len(dbMigrate); version++ {
tx, err := db.Begin()
if err != nil {
return err
}
migrateFn := dbMigrate[version]
fmt.Println("Migrating database schema version:", version+1)
if err := migrateFn(db); err != nil {
tx.Rollback()
return err
}
if err := setSchemaVersion(db, version+1); err != nil {
return err
}
if err := tx.Commit(); err != nil {
return err
}
}
return nil
}
func getSchemaVersion(db *DB) int {
_, err := db.Exec(`CREATE TABLE IF NOT EXISTS tbl_schema_ver (
version INT(5) UNSIGNED NOT NULL
)`)
if err != nil {
return -1
}
version := 0
db.Get(&version, `SELECT version FROM tbl_schema_ver`)
return version
}
func setSchemaVersion(db *DB, version int) error {
_, err := db.Exec(`DELETE FROM tbl_schema_ver`)
if err != nil {
return err
}
_, err = db.Exec(`INSERT INTO tbl_schema_ver (version) VALUES (?)`, version)
return err
}
func v1(db *DB) error {
// table: tbl_admin
_, err := db.Exec(`CREATE TABLE tbl_admin (
id INT(11) UNSIGNED NOT NULL AUTO_INCREMENT,
username VARCHAR(255) NOT NULL,
password VARCHAR(255) NOT NULL,
lastactive_ts INT(11) UNSIGNED NOT NULL DEFAULT 0,
created_ts INT(11) UNSIGNED NOT NULL DEFAULT 0,
PRIMARY KEY (id)
)`)
if err != nil {
return err
}
_, err = db.Exec(`ALTER TABLE tbl_admin ADD UNIQUE KEY (username)`)
if err != nil {
return err
}
// table: tbl_cron
_, err = db.Exec(`CREATE TABLE tbl_cron (
id INT(8) UNSIGNED NOT NULL AUTO_INCREMENT,
title VARCHAR(255) NOT NULL DEFAULT '',
slug VARCHAR(255) NOT NULL DEFAULT '',
description VARCHAR(255) NOT NULL DEFAULT '',
run_every INT(8) UNSIGNED NOT NULL DEFAULT 60 COMMENT 'in seconds',
last_run INT(11) UNSIGNED NOT NULL DEFAULT 0,
next_run INT(11) UNSIGNED NOT NULL DEFAULT 0,
run_time FLOAT(7,3) UNSIGNED NOT NULL DEFAULT 0.000,
cron_state TINYINT(1) UNSIGNED NOT NULL DEFAULT 0,
is_enabled TINYINT(1) UNSIGNED NOT NULL DEFAULT 1,
PRIMARY KEY (id)
)`)
if err != nil {
return err
}
_, err = db.Exec(`INSERT INTO tbl_cron (title, slug, description, run_every)
VALUES ('Delete old probe logs', 'delete_old_probe_logs', 'Delete old probe log from the database',120);`)
if err != nil {
return err
}
// table: tbl_node
_, err = db.Exec(`CREATE TABLE tbl_node (
id INT(11) UNSIGNED NOT NULL AUTO_INCREMENT,
protocol VARCHAR(6) NOT NULL DEFAULT 'http' COMMENT 'http | https',
hostname VARCHAR(255) NOT NULL,
port INT(6) UNSIGNED NOT NULL DEFAULT 0,
is_tor TINYINT(1) UNSIGNED NOT NULL DEFAULT 0,
is_available TINYINT(1) UNSIGNED NOT NULL DEFAULT 0,
nettype VARCHAR(100) NOT NULL COMMENT 'mainnet | stagenet | testnet',
height BIGINT(20) UNSIGNED NOT NULL DEFAULT 0,
adjusted_time BIGINT(20) UNSIGNED NOT NULL DEFAULT 0,
database_size BIGINT(20) UNSIGNED NOT NULL DEFAULT 0,
difficulty BIGINT(20) UNSIGNED NOT NULL DEFAULT 0,
version VARCHAR(200) NOT NULL DEFAULT '',
uptime float(5,2) UNSIGNED NOT NULL DEFAULT 0.00,
estimate_fee INT(9) UNSIGNED NOT NULL DEFAULT 0,
ip_addr VARCHAR(200) NOT NULL,
asn INT(9) UNSIGNED NOT NULL DEFAULT 0,
asn_name VARCHAR(255) NOT NULL DEFAULT '',
country VARCHAR(100) NOT NULL DEFAULT '',
country_name VARCHAR(255) NOT NULL DEFAULT '',
city VARCHAR(255) NOT NULL DEFAULT '',
lat FLOAT NOT NULL DEFAULT 0 COMMENT 'latitude',
lon FLOAT NOT NULL DEFAULT 0 COMMENT 'longitude',
date_entered INT(11) UNSIGNED NOT NULL DEFAULT 0,
last_checked INT(11) UNSIGNED NOT NULL DEFAULT 0,
last_check_status TEXT DEFAULT NULL,
cors_capable TINYINT(1) UNSIGNED NOT NULL DEFAULT 0,
PRIMARY KEY (id)
)`)
if err != nil {
return err
}
// table: tbl_prober
_, err = db.Exec(`CREATE TABLE tbl_prober (
id INT(9) UNSIGNED NOT NULL AUTO_INCREMENT,
name VARCHAR(255) NOT NULL,
api_key VARCHAR(36) NOT NULL,
last_submit_ts INT(11) UNSIGNED NOT NULL DEFAULT 0,
PRIMARY KEY (id)
)`)
if err != nil {
return err
}
_, err = db.Exec(`ALTER TABLE tbl_prober ADD UNIQUE KEY (api_key)`)
if err != nil {
return err
}
// table: tbl_probe_log
_, err = db.Exec(`CREATE TABLE tbl_probe_log (
id BIGINT(20) UNSIGNED NOT NULL AUTO_INCREMENT,
node_id INT(11) UNSIGNED NOT NULL DEFAULT 0,
prober_id INT(9) UNSIGNED NOT NULL DEFAULT 0,
is_available TINYINT(1) UNSIGNED NOT NULL DEFAULT 0,
height BIGINT(20) UNSIGNED NOT NULL DEFAULT 0,
adjusted_time BIGINT(20) UNSIGNED NOT NULL DEFAULT 0,
database_size BIGINT(20) UNSIGNED NOT NULL DEFAULT 0,
difficulty BIGINT(20) UNSIGNED NOT NULL DEFAULT 0,
estimate_fee INT(9) UNSIGNED NOT NULL DEFAULT 0,
date_checked INT(11) UNSIGNED NOT NULL DEFAULT 0,
failed_reason TEXT NOT NULL DEFAULT '',
fetch_runtime FLOAT(5,2) UNSIGNED NOT NULL DEFAULT 0.00,
PRIMARY KEY (id)
)`)
if err != nil {
return err
}
_, err = db.Exec(`ALTER TABLE tbl_probe_log ADD KEY (node_id)`)
if err != nil {
return err
}
return nil
}

View file

@ -1,18 +0,0 @@
#!/bin/sh
# Dump local dev database structure and required data from specific tables.
# ------------------------------------------------------------------------------
# shellcheck disable=SC2046 # Ignore SC2046: Quote this to prevent word splitting.
SD=$(dirname "$(readlink -f -- "$0")")
cd "$SD" || exit 1 && cd ".." || exit 1
## Structure only dump
mariadb-dump --no-data --skip-comments xmr_nodes | \
sed 's/ AUTO_INCREMENT=[0-9]*//g' > \
"./tools/resources/database/structure.sql"
## Dump `tbl_cron` only
# mariadb-dump --no-create-info --skip-comments xmr_nodes tbl_cron > \
# "./tools/resources/database/tbl_cron.sql"
# vim: set ts=4 sw=4 tw=0 et ft=sh:

View file

@ -1,116 +0,0 @@
/*!40101 SET @OLD_CHARACTER_SET_CLIENT=@@CHARACTER_SET_CLIENT */;
/*!40101 SET @OLD_CHARACTER_SET_RESULTS=@@CHARACTER_SET_RESULTS */;
/*!40101 SET @OLD_COLLATION_CONNECTION=@@COLLATION_CONNECTION */;
/*!40101 SET NAMES utf8mb4 */;
/*!40103 SET @OLD_TIME_ZONE=@@TIME_ZONE */;
/*!40103 SET TIME_ZONE='+00:00' */;
/*!40014 SET @OLD_UNIQUE_CHECKS=@@UNIQUE_CHECKS, UNIQUE_CHECKS=0 */;
/*!40014 SET @OLD_FOREIGN_KEY_CHECKS=@@FOREIGN_KEY_CHECKS, FOREIGN_KEY_CHECKS=0 */;
/*!40101 SET @OLD_SQL_MODE=@@SQL_MODE, SQL_MODE='NO_AUTO_VALUE_ON_ZERO' */;
/*!40111 SET @OLD_SQL_NOTES=@@SQL_NOTES, SQL_NOTES=0 */;
DROP TABLE IF EXISTS `tbl_admin`;
/*!40101 SET @saved_cs_client = @@character_set_client */;
/*!40101 SET character_set_client = utf8 */;
CREATE TABLE `tbl_admin` (
`id` bigint(30) unsigned NOT NULL AUTO_INCREMENT,
`username` varchar(200) NOT NULL,
`password` varchar(200) NOT NULL,
`lastactive_ts` int(11) unsigned NOT NULL DEFAULT 0,
`created_ts` int(11) unsigned NOT NULL DEFAULT 0,
PRIMARY KEY (`id`),
KEY `username` (`username`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci;
/*!40101 SET character_set_client = @saved_cs_client */;
DROP TABLE IF EXISTS `tbl_cron`;
/*!40101 SET @saved_cs_client = @@character_set_client */;
/*!40101 SET character_set_client = utf8 */;
CREATE TABLE `tbl_cron` (
`id` int(8) unsigned NOT NULL AUTO_INCREMENT,
`title` varchar(200) NOT NULL DEFAULT '',
`slug` varchar(200) NOT NULL DEFAULT '',
`description` varchar(200) NOT NULL DEFAULT '',
`run_every` int(8) unsigned NOT NULL DEFAULT 60 COMMENT 'in seconds',
`last_run` int(11) unsigned NOT NULL DEFAULT 0,
`next_run` int(11) unsigned NOT NULL DEFAULT 0,
`run_time` float(7,3) unsigned NOT NULL DEFAULT 0.000,
`cron_state` tinyint(1) unsigned NOT NULL DEFAULT 0,
`is_enabled` int(1) unsigned NOT NULL DEFAULT 1,
PRIMARY KEY (`id`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci;
/*!40101 SET character_set_client = @saved_cs_client */;
DROP TABLE IF EXISTS `tbl_node`;
/*!40101 SET @saved_cs_client = @@character_set_client */;
/*!40101 SET character_set_client = utf8 */;
CREATE TABLE `tbl_node` (
`id` bigint(20) unsigned NOT NULL AUTO_INCREMENT,
`protocol` varchar(6) NOT NULL DEFAULT 'http' COMMENT 'http | https',
`hostname` varchar(200) NOT NULL DEFAULT '',
`port` int(6) unsigned NOT NULL DEFAULT 0,
`is_tor` tinyint(1) unsigned NOT NULL DEFAULT 0,
`is_available` tinyint(1) unsigned NOT NULL DEFAULT 0,
`nettype` varchar(100) NOT NULL COMMENT 'mainnet | stagenet | testnet',
`height` bigint(20) unsigned NOT NULL DEFAULT 0,
`adjusted_time` bigint(20) unsigned NOT NULL DEFAULT 0,
`database_size` bigint(20) unsigned NOT NULL DEFAULT 0,
`difficulty` bigint(20) unsigned NOT NULL DEFAULT 0,
`version` varchar(200) NOT NULL DEFAULT '',
`uptime` float(5,2) unsigned NOT NULL DEFAULT 0.00,
`estimate_fee` int(9) unsigned NOT NULL DEFAULT 0,
`ip_addr` varchar(200) NOT NULL,
`asn` int(9) unsigned NOT NULL DEFAULT 0,
`asn_name` varchar(200) NOT NULL DEFAULT '',
`country` varchar(200) NOT NULL DEFAULT '',
`country_name` varchar(255) NOT NULL DEFAULT '',
`city` varchar(200) NOT NULL DEFAULT '',
`lat` float NOT NULL DEFAULT 0 COMMENT 'latitude',
`lon` float NOT NULL DEFAULT 0 COMMENT 'longitude',
`date_entered` bigint(20) unsigned NOT NULL DEFAULT 0,
`last_checked` bigint(20) unsigned NOT NULL DEFAULT 0,
`last_check_status` text DEFAULT NULL,
`cors_capable` tinyint(1) unsigned NOT NULL DEFAULT 0,
PRIMARY KEY (`id`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci;
/*!40101 SET character_set_client = @saved_cs_client */;
DROP TABLE IF EXISTS `tbl_probe_log`;
/*!40101 SET @saved_cs_client = @@character_set_client */;
/*!40101 SET character_set_client = utf8 */;
CREATE TABLE `tbl_probe_log` (
`id` bigint(20) unsigned NOT NULL AUTO_INCREMENT,
`node_id` bigint(20) unsigned NOT NULL DEFAULT 0,
`prober_id` int(9) unsigned NOT NULL DEFAULT 0,
`is_available` tinyint(1) unsigned NOT NULL DEFAULT 0,
`height` bigint(20) unsigned NOT NULL DEFAULT 0,
`adjusted_time` bigint(20) unsigned NOT NULL DEFAULT 0,
`database_size` bigint(20) unsigned NOT NULL DEFAULT 0,
`difficulty` bigint(20) unsigned NOT NULL DEFAULT 0,
`estimate_fee` int(9) unsigned NOT NULL DEFAULT 0,
`date_checked` bigint(20) unsigned NOT NULL DEFAULT 0,
`failed_reason` text NOT NULL DEFAULT '',
`fetch_runtime` float(5,2) unsigned NOT NULL DEFAULT 0.00,
PRIMARY KEY (`id`),
KEY `node_id` (`node_id`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci;
/*!40101 SET character_set_client = @saved_cs_client */;
DROP TABLE IF EXISTS `tbl_prober`;
/*!40101 SET @saved_cs_client = @@character_set_client */;
/*!40101 SET character_set_client = utf8 */;
CREATE TABLE `tbl_prober` (
`id` int(9) unsigned NOT NULL AUTO_INCREMENT,
`name` varchar(255) NOT NULL,
`api_key` varchar(36) NOT NULL,
`last_submit_ts` int(11) unsigned NOT NULL DEFAULT 0,
PRIMARY KEY (`id`),
UNIQUE KEY `api_key` (`api_key`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci;
/*!40101 SET character_set_client = @saved_cs_client */;
/*!40103 SET TIME_ZONE=@OLD_TIME_ZONE */;
/*!40101 SET SQL_MODE=@OLD_SQL_MODE */;
/*!40014 SET FOREIGN_KEY_CHECKS=@OLD_FOREIGN_KEY_CHECKS */;
/*!40014 SET UNIQUE_CHECKS=@OLD_UNIQUE_CHECKS */;
/*!40101 SET CHARACTER_SET_CLIENT=@OLD_CHARACTER_SET_CLIENT */;
/*!40101 SET CHARACTER_SET_RESULTS=@OLD_CHARACTER_SET_RESULTS */;
/*!40101 SET COLLATION_CONNECTION=@OLD_COLLATION_CONNECTION */;
/*!40111 SET SQL_NOTES=@OLD_SQL_NOTES */;

View file

@ -1,26 +0,0 @@
/*!40101 SET @OLD_CHARACTER_SET_CLIENT=@@CHARACTER_SET_CLIENT */;
/*!40101 SET @OLD_CHARACTER_SET_RESULTS=@@CHARACTER_SET_RESULTS */;
/*!40101 SET @OLD_COLLATION_CONNECTION=@@COLLATION_CONNECTION */;
/*!40101 SET NAMES utf8mb4 */;
/*!40103 SET @OLD_TIME_ZONE=@@TIME_ZONE */;
/*!40103 SET TIME_ZONE='+00:00' */;
/*!40014 SET @OLD_FOREIGN_KEY_CHECKS=@@FOREIGN_KEY_CHECKS, FOREIGN_KEY_CHECKS=0 */;
/*!40101 SET @OLD_SQL_MODE=@@SQL_MODE, SQL_MODE='NO_AUTO_VALUE_ON_ZERO' */;
/*!40111 SET @OLD_SQL_NOTES=@@SQL_NOTES, SQL_NOTES=0 */;
LOCK TABLES `tbl_cron` WRITE;
/*!40000 ALTER TABLE `tbl_cron` DISABLE KEYS */;
INSERT INTO `tbl_cron` VALUES
(1,'Delete old probe logs','delete_old_probe_logs','Delete old probe log from the database',120,0,0,0.007,0,1);
/*!40000 ALTER TABLE `tbl_cron` ENABLE KEYS */;
UNLOCK TABLES;
/*!40103 SET TIME_ZONE=@OLD_TIME_ZONE */;
/*!40101 SET SQL_MODE=@OLD_SQL_MODE */;
/*!40014 SET FOREIGN_KEY_CHECKS=@OLD_FOREIGN_KEY_CHECKS */;
/*!40101 SET CHARACTER_SET_CLIENT=@OLD_CHARACTER_SET_CLIENT */;
/*!40101 SET CHARACTER_SET_RESULTS=@OLD_CHARACTER_SET_RESULTS */;
/*!40101 SET COLLATION_CONNECTION=@OLD_COLLATION_CONNECTION */;
/*!40111 SET SQL_NOTES=@OLD_SQL_NOTES */;