From 13585a5e6aa24cfceea9ed6f6e0aaf68afed222b Mon Sep 17 00:00:00 2001 From: Calvin Montgomery Date: Sun, 30 Sep 2018 20:43:45 -0700 Subject: [PATCH] Replace raw DDL with knex table builder --- src/database.js | 22 ++-- src/database/tables.js | 267 +++++++++++++++++++---------------------- 2 files changed, 131 insertions(+), 158 deletions(-) diff --git a/src/database.js b/src/database.js index 06ce6e65..4655eb40 100644 --- a/src/database.js +++ b/src/database.js @@ -38,7 +38,7 @@ class Database { password: Config.get('mysql.password'), database: Config.get('mysql.database'), multipleStatements: true, // Legacy thing - charset: 'UTF8MB4_GENERAL_CI' + charset: 'utf8mb4' }, pool: { min: Config.get('mysql.pool-size'), @@ -80,8 +80,14 @@ module.exports.init = function (newDB) { .catch(error => { LOGGER.error('Initial database connection failed: %s', error.stack); process.exit(1); - }).then(() => { - process.nextTick(legacySetup); + }) + .then(() => tables.initTables()) + .then(() => { + require('./database/update').checkVersion(); + module.exports.loadAnnouncement(); + }).catch(error => { + LOGGER.error(error.stack); + process.exit(1); }); }; @@ -97,16 +103,6 @@ module.exports.getGlobalBanDB = function getGlobalBanDB() { return globalBanDB; }; -function legacySetup() { - tables.init(module.exports.query, function (err) { - if (err) { - return; - } - require("./database/update").checkVersion(); - module.exports.loadAnnouncement(); - }); -} - /** * Execute a database query */ diff --git a/src/database/tables.js b/src/database/tables.js index ab99514c..bfa3d513 100644 --- a/src/database/tables.js +++ b/src/database/tables.js @@ -1,155 +1,132 @@ const LOGGER = require('@calzoneman/jsli')('database/tables'); -const TBL_USERS = "" + - "CREATE TABLE IF NOT EXISTS `users` (" + - "`id` INT NOT NULL AUTO_INCREMENT," + - "`name` VARCHAR(20) NOT NULL," + - "`password` VARCHAR(64) NOT NULL," + - "`global_rank` INT NOT NULL," + - "`email` VARCHAR(255) NOT NULL," + - "`profile` TEXT CHARACTER SET utf8mb4 NOT NULL," + - "`ip` VARCHAR(39) NOT NULL," + - "`time` BIGINT NOT NULL," + - "`name_dedupe` VARCHAR(20) DEFAULT NULL," + - "PRIMARY KEY(`id`)," + - "UNIQUE(`name`)," + - "UNIQUE(`name_dedupe`)) " + - "CHARACTER SET utf8"; -const TBL_CHANNELS = "" + - "CREATE TABLE IF NOT EXISTS `channels` (" + - "`id` INT NOT NULL AUTO_INCREMENT," + - "`name` VARCHAR(30) NOT NULL," + - "`owner` VARCHAR(20) NOT NULL," + - "`time` BIGINT NOT NULL," + - "`last_loaded` TIMESTAMP NOT NULL DEFAULT 0," + - "`owner_last_seen` TIMESTAMP NOT NULL DEFAULT 0," + - "PRIMARY KEY (`id`)," + - "UNIQUE(`name`)," + - "INDEX(`owner`)," + - "INDEX(`last_loaded`)," + - "INDEX(`owner_last_seen`)) " + - "CHARACTER SET utf8"; +export async function initTables() { + const knex = require('../database').getDB().knex; -const TBL_GLOBAL_BANS = "" + - "CREATE TABLE IF NOT EXISTS `global_bans` (" + - "`ip` VARCHAR(39) NOT NULL," + - "`reason` VARCHAR(255) CHARACTER SET utf8mb4 NOT NULL," + - "PRIMARY KEY (`ip`)) " + - "CHARACTER SET utf8"; + async function ensureTable(name, structure) { + if (!await knex.schema.hasTable(name)) { + LOGGER.info('Creating table %s', name); + await knex.schema.createTable(name, structure); + } + } -const TBL_PASSWORD_RESET = "" + - "CREATE TABLE IF NOT EXISTS `password_reset` (" + - "`ip` VARCHAR(39) NOT NULL," + - "`name` VARCHAR(20) NOT NULL," + - "`hash` VARCHAR(64) NOT NULL," + - "`email` VARCHAR(255) NOT NULL," + - "`expire` BIGINT NOT NULL," + - "PRIMARY KEY (`name`))" + - "CHARACTER SET utf8"; + // TODO: consider un-utf8ing columns that are always ASCII + // Leaving for now for backwards compatibility -const TBL_USER_PLAYLISTS = "" + - "CREATE TABLE IF NOT EXISTS `user_playlists` (" + - "`user` VARCHAR(20) NOT NULL," + - "`name` VARCHAR(255) NOT NULL," + - "`contents` MEDIUMTEXT NOT NULL," + - "`count` INT NOT NULL," + - "`duration` INT NOT NULL," + - "PRIMARY KEY (`user`, `name`))" + - "CHARACTER SET utf8"; + // TODO: enforce foreign key constraints for tables missing them -const TBL_ALIASES = "" + - "CREATE TABLE IF NOT EXISTS `aliases` (" + - "`visit_id` INT NOT NULL AUTO_INCREMENT," + - "`ip` VARCHAR(39) NOT NULL," + - "`name` VARCHAR(20) NOT NULL," + - "`time` BIGINT NOT NULL," + - "PRIMARY KEY (`visit_id`), INDEX (`ip`)" + - ")"; - -const TBL_META = "" + - "CREATE TABLE IF NOT EXISTS `meta` (" + - "`key` VARCHAR(255) NOT NULL," + - "`value` TEXT NOT NULL," + - "PRIMARY KEY (`key`))" + - "CHARACTER SET utf8"; - -const TBL_LIBRARIES = "" + - "CREATE TABLE IF NOT EXISTS `channel_libraries` (" + - "`id` VARCHAR(255) NOT NULL," + - "`title` VARCHAR(255) CHARACTER SET utf8mb4 NOT NULL," + - "`seconds` INT NOT NULL," + - "`type` VARCHAR(2) NOT NULL," + - "`meta` TEXT NOT NULL," + - "`channel` VARCHAR(30) NOT NULL," + - "PRIMARY KEY(`id`, `channel`), INDEX(`channel`, `title`(227))" + - ") CHARACTER SET utf8"; - -const TBL_RANKS = "" + - "CREATE TABLE IF NOT EXISTS `channel_ranks` (" + - "`name` VARCHAR(20) NOT NULL," + - "`rank` INT NOT NULL," + - "`channel` VARCHAR(30) NOT NULL," + - "PRIMARY KEY(`name`, `channel`)" + - ") CHARACTER SET utf8"; - -const TBL_BANS = "" + - "CREATE TABLE IF NOT EXISTS `channel_bans` (" + - "`id` INT NOT NULL AUTO_INCREMENT," + - "`ip` VARCHAR(39) NOT NULL," + - "`name` VARCHAR(20) NOT NULL," + - "`bannedby` VARCHAR(20) NOT NULL," + - "`reason` VARCHAR(255) CHARACTER SET utf8mb4 NOT NULL," + - "`channel` VARCHAR(30) NOT NULL," + - "PRIMARY KEY (`id`, `channel`), UNIQUE (`name`, `ip`, `channel`), " + - "INDEX (`ip`, `channel`), INDEX (`name`, `channel`)" + - ") CHARACTER SET utf8"; - -const TBL_CHANNEL_DATA = "" + - "CREATE TABLE IF NOT EXISTS `channel_data` (" + - "`channel_id` INT NOT NULL," + - "`key` VARCHAR(20) NOT NULL," + - "`value` MEDIUMTEXT CHARACTER SET utf8mb4 NOT NULL," + - "PRIMARY KEY (`channel_id`, `key`)," + - "FOREIGN KEY (`channel_id`) REFERENCES `channels`(`id`) ON DELETE CASCADE" + - ") CHARACTER SET utf8"; - -module.exports.init = function (queryfn, cb) { - var tables = { - users: TBL_USERS, - channels: TBL_CHANNELS, - channel_libraries: TBL_LIBRARIES, - channel_ranks: TBL_RANKS, - channel_bans: TBL_BANS, - global_bans: TBL_GLOBAL_BANS, - password_reset: TBL_PASSWORD_RESET, - user_playlists: TBL_USER_PLAYLISTS, - aliases: TBL_ALIASES, - meta: TBL_META, - channel_data: TBL_CHANNEL_DATA - }; - - var AsyncQueue = require("../asyncqueue"); - var aq = new AsyncQueue(); - var hasError = false; - Object.keys(tables).forEach(function (tbl) { - aq.queue(function (lock) { - queryfn(tables[tbl], function (err) { - if (err) { - LOGGER.error( - 'Failed to create table %s: %s', - tbl, - err.stack - ); - hasError = true; - } - lock.release(); - }); - }); + await ensureTable('users', t => { + t.charset('utf8'); + t.increments('id').notNullable().primary(); + t.string('name', 20).notNullable().unique(); + t.string('password', 60).notNullable(); + t.integer('global_rank').notNullable(); + t.string('email', 255); + // UTF8MB4 required for non-BMP Unicode -- Just MySQL things (tm) + t.specificType('profile', 'text character set utf8mb4 not null'); + t.string('ip', 39).notNullable(); + // Registration time, TODO convert to timestamp + t.bigint('time').notNullable(); + t.string('name_dedupe', 20).defaultTo(null); }); - aq.queue(function (lock) { - lock.release(); - cb(hasError); + await ensureTable('channels', t => { + t.charset('utf8'); + t.increments('id').notNullable().primary(); + t.string('name', 30).notNullable().unique(); + t.string('owner', 20).notNullable().index(); + // Registration time, TODO convert to timestamp + t.bigInteger('time').notNullable(); + t.timestamp('last_loaded').notNullable() + .defaultTo(knex.raw('0')); + t.timestamp('owner_last_seen').notNullable() + .defaultTo(knex.raw('0')); }); -}; + + await ensureTable('channel_data', t => { + t.charset('utf8'); + t.integer('channel_id').notNullable() + .unsigned() + .references('id').inTable('channels') + .onDelete('cascade'); + t.string('key', 20).notNullable(); + t.specificType('value', 'mediumtext character set utf8mb4 not null'); + t.primary(['channel_id', 'key']); + }); + + await ensureTable('global_bans', t => { + t.charset('utf8'); + t.string('ip', 39).notNullable().primary(); + t.string('reason', 255).notNullable(); + }); + + await ensureTable('password_reset', t => { + t.charset('utf8'); + t.string('ip', 39).notNullable(); + t.string('name', 20).notNullable().primary(); + t.string('hash', 64).notNullable(); + t.string('email', 255).notNullable(); + // TODO consider converting to timestamp + t.bigint('expire').notNullable(); + }); + + await ensureTable('user_playlists', t => { + t.charset('utf8'); + t.string('user', 20).notNullable(); + t.string('name', 255).notNullable(); + t.specificType('contents', 'mediumtext character set utf8mb4 not null'); + t.integer('count').notNullable(); + t.integer('duration').notNullable(); + t.primary(['user', 'name']); + }); + + await ensureTable('aliases', t => { + t.charset('utf8'); + t.increments('visit_id').notNullable().primary(); + t.string('ip', 39).notNullable().index(); + t.string('name', 20).notNullable(); + // TODO consider converting to timestamp + t.bigint('time').notNullable(); + }); + + await ensureTable('meta', t => { + t.charset('utf8'); + t.string('key', 255).notNullable().primary(); + t.text('value').notNullable(); + }); + + await ensureTable('channel_libraries', t => { + t.charset('utf8'); + t.string('id', 255).notNullable(); + t.specificType('title', 'varchar(255) character set utf8mb4 not null'); + t.integer('seconds').notNullable(); + t.string('type', 2).notNullable(); + t.text('meta').notNullable(); + t.string('channel', 30).notNullable(); + t.primary(['id', 'channel']); + // TODO replace title index with FTS or elasticsearch or something + t.index(['channel', knex.raw('`title`(227)')], 'channel_libraries_channel_title'); + }); + + await ensureTable('channel_ranks', t => { + t.charset('utf8'); + t.string('name', 20).notNullable(); + t.integer('rank').notNullable(); + t.string('channel', 30).notNullable(); + t.primary(['name', 'channel']); + }); + + await ensureTable('channel_bans', t => { + t.charset('utf8'); + t.increments('id').notNullable().primary(); + t.string('ip', 39).notNullable(); + t.string('name', 20).notNullable(); + t.string('bannedby', 20).notNullable(); + t.specificType('reason', 'varchar(255) character set utf8mb4 not null'); + t.string('channel', 30).notNullable(); + t.unique(['name', 'ip', 'channel']); + t.index(['ip', 'channel']); + t.index(['name', 'channel']); + }); +}