diff --git a/.changeset/big-cats-yell.md b/.changeset/big-cats-yell.md new file mode 100644 index 0000000..6bb82d0 --- /dev/null +++ b/.changeset/big-cats-yell.md @@ -0,0 +1,5 @@ +--- +'@emigrate/mysql': minor +--- + +Implement the first version of the MySQL plugin package. It's three plugins in one: a storage plugin for storing migration history in a MySQL database, a loader plugin for executing migration files written in plain sql and a generator plugin for generating migration file skeletons with the .sql extension. diff --git a/packages/mysql/README.md b/packages/mysql/README.md new file mode 100644 index 0000000..4cf64f8 --- /dev/null +++ b/packages/mysql/README.md @@ -0,0 +1,177 @@ +# @emigrate/storage-mysql + +A MySQL plugin for Emigrate. Uses a MySQL database for storing migration history. Can load and generate .sql migration files. + +The table used for storing the migration history is compatible with the [immigration-mysql](https://github.com/joakimbeng/immigration-mysql) package, so you can use this together with the [@emigrate/cli](../cli) as a drop-in replacement for that package. + +## Description + +This plugin is actually three different Emigrate plugins in one: + +1. A [storage plugin](#using-the-storage-plugin) for storing the migration history in a MySQL database. +2. A [loader plugin](#using-the-loader-plugin) for loading .sql migration files and be able to execute them as part of the migration process. +3. A [generator plugin](#using-the-generator-plugin) for generating .sql migration files. + +## Installation + +Install the plugin in your project, alongside the Emigrate CLI: + +```bash +npm install --save-dev @emigrate/cli @emigrate/mysql +``` + +## Usage + +### Using the storage plugin + +See [Options](#options) below for the default values and how to configure the plugin using environment variables. + +Configure the storage in your `emigrate.config.js` file: + +```js +export default { + directory: 'migrations', + storage: 'mysql', // the @emigrate/ prefix is optional +}; +``` + +Or use the CLI options `--storage` (or `-s`) + +```bash +emigrate up --storage mysql # the @emigrate/ prefix is optional +``` + +#### Storage plugin with custom options + +Configure the storage in your `emigrate.config.js` file by importing the `createMysqlStorage` function (see [Options](#options) for available options). + +In this mode the plugin will _not_ use any of the environment variables for configuration. + +```js +import { createMysqlStorage } from '@emigrate/mysql'; + +export default { + directory: 'migrations', + storage: createMysqlStorage({ table: 'migrations', connection: { ... } }), // All connection options are passed to mysql.createConnection() +}; +``` + +Or use the CLI option `--storage` (or `-s`) and use environment variables (see [Options](#options) for available variables). + +```bash +MYSQL_URL=mysql://user:pass@host/db emigrate up --storage mysql # the @emigrate/ prefix is optional +``` + +### Using the loader plugin + +The loader plugin is used to transform .sql migration files into JavaScript functions that can be executed by the "up" command. + +See [Options](#options) below for the default values and how to configure the plugin using environment variables. + +Configure the loader in your `emigrate.config.js` file: + +```js +export default { + directory: 'migrations', + plugins: ['mysql'], // the @emigrate/ prefix is optional +}; +``` + +Or by importing the default export from the plugin: + +```js +import mysqlPlugin from '@emigrate/mysql'; + +export default { + directory: 'migrations', + plugins: [mysqlPlugin], +}; +``` + +**NOTE:** Using the root level `plugins` option will load the plugin for all commands, which means the [generator plugin](#using-the-generator-plugin) will be used by default for the "new" command as well. If you only want to use the loader plugin, use the `up.plugins` option instead: + +```js +export default { + directory: 'migrations', + up: { + plugins: ['mysql'], // the @emigrate/ prefix is optional + // or: + plugins: [import('@emigrate/mysql')], + }, +}; +``` + +The loader plugin can also be loaded using the CLI option `--plugin` (or `-p`) together with the "up" command: + +```bash +emigrate up --plugin mysql # the @emigrate/ prefix is optional +``` + +### Using the generator plugin + +The generator plugin is used to generate skeleton .sql migration files inside your migration directory. + +Configure the generator in your `emigrate.config.js` file: + +```js +export default { + directory: 'migrations', + plugins: ['mysql'], // the @emigrate/ prefix is optional +}; +``` + +Or by importing the default export from the plugin: + +```js +import mysqlPlugin from '@emigrate/mysql'; + +export default { + directory: 'migrations', + plugins: [mysqlPlugin], +}; +``` + +**NOTE:** Using the root level `plugins` option will load the plugin for all commands, which means the [loader plugin](#using-the-loader-plugin) will be used by default for the "up" command as well. If you only want to use the generator plugin, use the `new.plugins` option instead: + +```js +export default { + directory: 'migrations', + new: { + plugins: ['mysql'], // the @emigrate/ prefix is optional + // or: + plugins: [import('@emigrate/mysql')], + }, +}; +``` + +The generator plugin can also be loaded using the CLI option `--plugin` (or `-p`) together with the "new" command: + +```bash +emigrate new --plugin mysql My new migration file # the @emigrate/ prefix is optional +``` + +#### Loader plugin with custom options + +Configure the loader in your `emigrate.config.js` file by importing the `createMysqlLoader` function (see [Options](#options) for available options). + +In this mode the plugin will _not_ use any of the environment variables for configuration. + +```js +import { createMysqlLoader } from '@emigrate/mysql'; + +export default { + directory: 'migrations', + plugins: [ + createMysqlLoader({ connection: { ... } }), // All connection options are passed to mysql.createConnection() + ], +}; +``` + +## Options + +The storage plugin accepts the following options: + +| Option | Applies to | Description | Default | Environment variable | +| ------------ | -------------------------- | -------------------------------------------------------------------------------------------------------------------- | ------------ | ---------------------------------------------------------------------------------------------- | +| `table` | storage plugin | The name of the table to use for storing the migrations. | `migrations` | `MYSQL_TABLE` | +| `connection` | storage and loader plugins | The connection options to pass to [`mysql.createConnection()`](https://github.com/mysqljs/mysql#connection-options). | `{}` | `MYSQL_URL` or `MYSQL_HOST`, `MYSQL_PORT`, `MYSQL_USER`, `MYSQL_PASSWORD` and `MYSQL_DATABASE` | diff --git a/packages/mysql/package.json b/packages/mysql/package.json new file mode 100644 index 0000000..95f321a --- /dev/null +++ b/packages/mysql/package.json @@ -0,0 +1,49 @@ +{ + "name": "@emigrate/mysql", + "version": "0.0.0", + "publishConfig": { + "access": "public" + }, + "description": "A MySQL plugin for Emigrate. Uses a MySQL database for storing migration history. Can load and generate .sql migration files.", + "main": "dist/index.js", + "types": "dist/index.d.js", + "type": "module", + "exports": { + ".": { + "import": "./dist/index.js", + "types": "./dist/index.d.ts" + } + }, + "files": [ + "dist" + ], + "scripts": { + "build": "tsc --pretty", + "build:watch": "tsc --pretty --watch", + "lint": "xo --cwd=../.. $(pwd)" + }, + "keywords": [ + "emigrate", + "emigrate-storage", + "emigrate-loader", + "emigrate-plugin", + "emigrate-generator", + "migrations", + "mysql" + ], + "author": "Aboviq AB (https://www.aboviq.com)", + "homepage": "https://github.com/aboviq/emigrate/tree/main/packages/mysql#readme", + "repository": "https://github.com/aboviq/emigrate/tree/main/packages/mysql", + "bugs": "https://github.com/aboviq/emigrate/issues", + "license": "MIT", + "dependencies": { + "@emigrate/plugin-tools": "workspace:*", + "mysql2": "3.6.5" + }, + "devDependencies": { + "@emigrate/tsconfig": "workspace:*" + }, + "volta": { + "extends": "../../package.json" + } +} diff --git a/packages/mysql/src/index.ts b/packages/mysql/src/index.ts new file mode 100644 index 0000000..6f175c1 --- /dev/null +++ b/packages/mysql/src/index.ts @@ -0,0 +1,286 @@ +import process from 'node:process'; +import fs from 'node:fs/promises'; +import { + createConnection, + createPool, + escapeId, + type ConnectionOptions, + type PoolOptions, + type Pool, + type ResultSetHeader, + type RowDataPacket, +} from 'mysql2/promise'; +import { + type MigrationMetadata, + type EmigrateStorage, + type LoaderPlugin, + type Storage, + type MigrationStatus, + type MigrationMetadataFinished, + type GenerateMigrationFunction, + type GeneratorPlugin, +} from '@emigrate/plugin-tools/types'; +import { getTimestampPrefix, sanitizeMigrationName } from '@emigrate/plugin-tools'; + +const defaultTable = 'migrations'; + +export type MysqlStorageOptions = { + table?: string; + /** + * @see https://github.com/mysqljs/mysql#connection-options + */ + connection: PoolOptions | string; +}; + +export type MysqlLoaderOptions = { + /** + * @see https://github.com/mysqljs/mysql#connection-options + */ + connection: ConnectionOptions | string; +}; + +const getConnection = async (connection: ConnectionOptions | string) => { + if (typeof connection === 'string') { + const uri = new URL(connection); + + // client side connectTimeout is unstable in mysql2 library + // it throws an error you can't catch and crashes node + // best to leave this at 0 (disabled) + uri.searchParams.set('connectTimeout', '0'); + uri.searchParams.set('multipleStatements', 'true'); + + return createConnection(uri.toString()); + } + + return createConnection({ + ...connection, + // client side connectTimeout is unstable in mysql2 library + // it throws an error you can't catch and crashes node + // best to leave this at 0 (disabled) + connectTimeout: 0, + multipleStatements: true, + }); +}; + +const getPool = (connection: PoolOptions | string) => { + if (typeof connection === 'string') { + const uri = new URL(connection); + + // client side connectTimeout is unstable in mysql2 library + // it throws an error you can't catch and crashes node + // best to leave this at 0 (disabled) + uri.searchParams.set('connectTimeout', '0'); + + return createPool(uri.toString()); + } + + return createPool({ + ...connection, + // client side connectTimeout is unstable in mysql2 library + // it throws an error you can't catch and crashes node + // best to leave this at 0 (disabled) + connectTimeout: 0, + }); +}; + +type HistoryEntry = { + name: string; + status: MigrationStatus; + date: Date; + error?: unknown; +}; + +const lockMigration = async (pool: Pool, table: string, migration: MigrationMetadata) => { + const [result] = await pool.execute({ + sql: ` + INSERT INTO ${escapeId(table)} (name, status, date) + VALUES (?, ?, NOW()) + ON DUPLICATE KEY UPDATE name = name + `, + values: [migration.name, 'locked'], + }); + + return result.affectedRows === 1; +}; + +const unlockMigration = async (pool: Pool, table: string, migration: MigrationMetadata) => { + const [result] = await pool.execute({ + sql: ` + DELETE FROM ${escapeId(table)} + WHERE + name = ? + AND status = ? + `, + values: [migration.name, 'locked'], + }); + + return result.affectedRows === 1; +}; + +const finishMigration = async (pool: Pool, table: string, migration: MigrationMetadataFinished) => { + const [result] = await pool.execute({ + sql: ` + UPDATE + ${escapeId(table)} + SET + status = ?, + date = NOW() + WHERE + name = ? + AND status = ? + `, + values: [migration.status, migration.name, 'locked'], + }); + + return result.affectedRows === 1; +}; + +const deleteMigration = async (pool: Pool, table: string, migration: MigrationMetadata) => { + const [result] = await pool.execute({ + sql: ` + DELETE FROM ${escapeId(table)} + WHERE + name = ? + AND status <> ? + `, + values: [migration.name, 'locked'], + }); + + return result.affectedRows === 1; +}; + +const initializeTable = async (pool: Pool, table: string) => { + // This table definition is compatible with the one used by the immigration-mysql package + await pool.execute(` + CREATE TABLE IF NOT EXISTS ${escapeId(table)} ( + name varchar(255) not null primary key, + status varchar(32), + date datetime not null + ) Engine=InnoDB; + `); +}; + +export const createMysqlStorage = ({ table = defaultTable, connection }: MysqlStorageOptions): EmigrateStorage => { + return { + async initializeStorage() { + const pool = getPool(connection); + + try { + await initializeTable(pool, table); + + const storage: Storage = { + async lock(migrations) { + const lockedMigrations: MigrationMetadata[] = []; + + for await (const migration of migrations) { + if (await lockMigration(pool, table, migration)) { + lockedMigrations.push(migration); + } + } + + return lockedMigrations; + }, + async unlock(migrations) { + for await (const migration of migrations) { + await unlockMigration(pool, table, migration); + } + }, + async remove(migration) { + await deleteMigration(pool, table, migration); + }, + async *getHistory() { + const [rows] = await pool.execute>({ + sql: ` + SELECT + * + FROM + ${escapeId(table)} + WHERE + status <> ? + ORDER BY + date ASC + `, + values: ['locked'], + }); + + for (const row of rows) { + yield { + name: row.name, + status: row.status, + date: new Date(row.date), + // FIXME: Migrate the migrations table to support the error column + error: row.status === 'failed' ? new Error('Unknown error reason') : undefined, + }; + } + }, + async onSuccess(migration) { + await finishMigration(pool, table, migration); + }, + async onError(migration, error) { + await finishMigration(pool, table, { ...migration, status: 'failed', error }); + }, + }; + + return storage; + } finally { + await pool.end(); + } + }, + }; +}; + +export const { initializeStorage } = createMysqlStorage({ + table: process.env['MYSQL_TABLE'], + connection: process.env['MYSQL_URL'] ?? { + host: process.env['MYSQL_HOST'], + port: process.env['MYSQL_PORT'] ? Number.parseInt(process.env['MYSQL_PORT'], 10) : undefined, + user: process.env['MYSQL_USER'], + password: process.env['MYSQL_PASSWORD'], + database: process.env['MYSQL_DATABASE'], + }, +}); + +export const createMysqlLoader = ({ connection }: MysqlLoaderOptions): LoaderPlugin => { + return { + loadableExtensions: ['.sql'], + async loadMigration(migration) { + return async () => { + const contents = await fs.readFile(migration.filePath, 'utf8'); + const conn = await getConnection(connection); + + try { + await conn.query(contents); + } finally { + await conn.end(); + } + }; + }, + }; +}; + +export const { loadableExtensions, loadMigration } = createMysqlLoader({ + connection: process.env['MYSQL_URL'] ?? { + host: process.env['MYSQL_HOST'], + port: process.env['MYSQL_PORT'] ? Number.parseInt(process.env['MYSQL_PORT'], 10) : undefined, + user: process.env['MYSQL_USER'], + password: process.env['MYSQL_PASSWORD'], + database: process.env['MYSQL_DATABASE'], + }, +}); + +export const generateMigration: GenerateMigrationFunction = async (name) => { + return { + filename: `${getTimestampPrefix()}_${sanitizeMigrationName(name)}.sql`, + content: `-- Migration: ${name} +`, + }; +}; + +const defaultExport: EmigrateStorage & LoaderPlugin & GeneratorPlugin = { + initializeStorage, + loadableExtensions, + loadMigration, + generateMigration, +}; + +export default defaultExport; diff --git a/packages/mysql/tsconfig.json b/packages/mysql/tsconfig.json new file mode 100644 index 0000000..1cfcebb --- /dev/null +++ b/packages/mysql/tsconfig.json @@ -0,0 +1,8 @@ +{ + "extends": "@emigrate/tsconfig/build.json", + "compilerOptions": { + "outDir": "dist" + }, + "include": ["src"], + "exclude": ["node_modules", "dist"] +} diff --git a/pnpm-lock.yaml b/pnpm-lock.yaml index 35788f5..d847333 100644 --- a/pnpm-lock.yaml +++ b/pnpm-lock.yaml @@ -82,6 +82,19 @@ importers: specifier: workspace:* version: link:../tsconfig + packages/mysql: + dependencies: + '@emigrate/plugin-tools': + specifier: workspace:* + version: link:../plugin-tools + mysql2: + specifier: 3.6.5 + version: 3.6.5 + devDependencies: + '@emigrate/tsconfig': + specifier: workspace:* + version: link:../tsconfig + packages/plugin-generate-js: dependencies: '@emigrate/plugin-tools': @@ -1979,6 +1992,11 @@ packages: object-keys: 1.1.1 dev: false + /denque@2.1.0: + resolution: {integrity: sha512-HVQE3AAb/pxF8fQAoiqpvg9i3evqug3hoiwakOyZAwJm+6vZehbkYXZ0l4JxS+I3QxM97v5aaRNhj8v5oBhekw==} + engines: {node: '>=0.10'} + dev: false + /detect-indent@6.1.0: resolution: {integrity: sha512-reYkTUJAZb9gUuZ2RvVCNhVHdg62RHnJ7WJl8ftMi4diZ6NWlciOzQN88pUhSELEwflJht4oQDv0F0BMlwaYtA==} engines: {node: '>=8'} @@ -2865,6 +2883,12 @@ packages: resolution: {integrity: sha512-xckBUXyTIqT97tq2x2AMb+g163b5JFysYk0x4qxNFwbfQkmNZoiRHb6sPzI9/QV33WeuvVYBUIiD4NzNIyqaRQ==} dev: false + /generate-function@2.3.1: + resolution: {integrity: sha512-eeB5GfMNeevm/GRYq20ShmsaGcmI81kIX2K9XQx5miC8KdHaC6Jm0qQ8ZNeGOi7wYB8OsdxKs+Y2oVuTFuVwKQ==} + dependencies: + is-property: 1.0.2 + dev: false + /get-caller-file@2.0.5: resolution: {integrity: sha512-DyFP3BM/3YHTQOCUL/w0OZHR0lpKeGrxotcHWcqNEdnltqFwXVfhEBQ94eIo34AfQpo0rGki4cyIiftY06h2Fg==} engines: {node: 6.* || 8.* || >= 10.*} @@ -3167,6 +3191,13 @@ packages: safer-buffer: 2.1.2 dev: false + /iconv-lite@0.6.3: + resolution: {integrity: sha512-4fCk79wshMdzMp2rH06qWrJE4iolqLhCUH+OiuIgU++RB0+94NlDL81atO7GX55uUKueo0txHNtvEyI6D7WdMw==} + engines: {node: '>=0.10.0'} + dependencies: + safer-buffer: 2.1.2 + dev: false + /ieee754@1.2.1: resolution: {integrity: sha512-dcyqhDvX1C46lXZcVqCpK+FtMRQVdIMN6/Df5js2zouUsqG7I6sFxitIC+7KYK29KdXOLHdu9zL4sFnoVQnqaA==} dev: false @@ -3421,6 +3452,10 @@ packages: engines: {node: '>=0.10.0'} dev: false + /is-property@1.0.2: + resolution: {integrity: sha512-Ks/IoX00TtClbGQr4TWXemAnktAQvYB7HzcCxDGqEZU6oCmb2INHuOoKxbtR+HFkmYWBKv/dOZtGRiAjDhj92g==} + dev: false + /is-proto-prop@2.0.0: resolution: {integrity: sha512-jl3NbQ/fGLv5Jhan4uX+Ge9ohnemqyblWVVCpAvtTQzNFvV2xhJq+esnkIbYQ9F1nITXoLfDDQLp7LBw/zzncg==} dependencies: @@ -3854,6 +3889,10 @@ packages: wrap-ansi: 9.0.0 dev: false + /long@5.2.3: + resolution: {integrity: sha512-lcHwpNoggQTObv5apGNCTdJrO69eHOZMi4BNC+rTLER8iHAqGrUVeLh/irVIM7zTw2bOXA8T6uNPeujwOLg/2Q==} + dev: false + /lowercase-keys@1.0.1: resolution: {integrity: sha512-G2Lj61tXDnVFFOi8VZds+SoQjtQC3dgokKdDG2mTm1tx4m50NUHBOZSBwQQHyy0V12A0JTG4icfZQH+xPyh8VA==} engines: {node: '>=0.10.0'} @@ -3883,6 +3922,16 @@ packages: yallist: 4.0.0 dev: false + /lru-cache@7.18.3: + resolution: {integrity: sha512-jumlc0BIUrS3qJGgIkWZsyfAM7NCWiBcCDhnd+3NNM5KbBmLTgHVfWBcg6W+rLUsIpzpERPsvwUP7CckAQSOoA==} + engines: {node: '>=12'} + dev: false + + /lru-cache@8.0.5: + resolution: {integrity: sha512-MhWWlVnuab1RG5/zMRRcVGXZLCXrZTgfwMikgzCegsPnG62yDQo5JnqKkrK4jO5iKqDAZGItAqN5CtKBCBWRUA==} + engines: {node: '>=16.14'} + dev: false + /map-obj@1.0.1: resolution: {integrity: sha512-7N/q3lyZ+LVCp7PzuxrJr4KMbBE2hW7BT7YNia330OFxIf4d3r5zVpicP2650l7CPN6RM9zOJRl3NGpqSiw3Eg==} engines: {node: '>=0.10.0'} @@ -4034,6 +4083,27 @@ packages: resolution: {integrity: sha512-sGkPx+VjMtmA6MX27oA4FBFELFCZZ4S4XqeGOXCv68tT+jb3vk/RyaKWP0PTKyWtmLSM0b+adUTEvbs1PEaH2w==} dev: false + /mysql2@3.6.5: + resolution: {integrity: sha512-pS/KqIb0xlXmtmqEuTvBXTmLoQ5LmAz5NW/r8UyQ1ldvnprNEj3P9GbmuQQ2J0A4LO+ynotGi6TbscPa8OUb+w==} + engines: {node: '>= 8.0'} + dependencies: + denque: 2.1.0 + generate-function: 2.3.1 + iconv-lite: 0.6.3 + long: 5.2.3 + lru-cache: 8.0.5 + named-placeholders: 1.1.3 + seq-queue: 0.0.5 + sqlstring: 2.3.3 + dev: false + + /named-placeholders@1.1.3: + resolution: {integrity: sha512-eLoBxg6wE/rZkJPhU/xRX1WTpkFEwDJEN96oxFrTsqBdbT5ec295Q+CoHrL9IT0DipqKhmGcaZmwOt8OON5x1w==} + engines: {node: '>=12.0.0'} + dependencies: + lru-cache: 7.18.3 + dev: false + /natural-compare@1.4.0: resolution: {integrity: sha512-OWND8ei3VtNC9h7V60qff3SVobHr996CTwgxubgyQYEpg290h9J0buyECNNJexkFm5sOajh5G116RYA1c8ZMSw==} dev: false @@ -4849,6 +4919,10 @@ packages: lru-cache: 6.0.0 dev: false + /seq-queue@0.0.5: + resolution: {integrity: sha512-hr3Wtp/GZIc/6DAGPDcV4/9WoZhjrkXsi5B/07QgX8tsdc6ilr7BFM6PM6rbdAX1kFSDYeZGLipIZZKyQP0O5Q==} + dev: false + /serialize-javascript@6.0.1: resolution: {integrity: sha512-owoXEFjWRllis8/M1Q+Cw5k8ZH40e3zhp/ovX+Xr/vi1qj6QesbyXXViFbpNvWvPNAD62SutwEXavefrLJWj7w==} dependencies: @@ -5029,6 +5103,11 @@ packages: resolution: {integrity: sha512-D9cPgkvLlV3t3IzL0D0YLvGA9Ahk4PcvVwUbN0dSGr1aP0Nrt4AEnTUbuGvquEC0mA64Gqt1fzirlRs5ibXx8g==} dev: false + /sqlstring@2.3.3: + resolution: {integrity: sha512-qC9iz2FlN7DQl3+wjwn3802RTyjCx7sDvfQEXchwa6CWOx07/WVfh91gBmQ9fahw8snwGEWU3xGzOt4tFyHLxg==} + engines: {node: '>= 0.6'} + dev: false + /stream-transform@2.1.3: resolution: {integrity: sha512-9GHUiM5hMiCi6Y03jD2ARC1ettBXkQBoQAe7nJsPknnI0ow10aXjTnew8QtYQmLjzn974BnmWEAJgCY6ZP1DeQ==} dependencies: