├── .gitattributes ├── .eslintignore ├── .github ├── FUNDING.yml ├── PULL_REQUEST_TEMPLATE.md ├── ISSUE_TEMPLATE │ ├── feature_request.md │ └── bug_report.md └── workflows │ └── test.yml ├── .gitignore ├── .npmignore ├── .prettierrc ├── .editorconfig ├── .eslintrc.json ├── SECURITY.md ├── LICENSE ├── package.json ├── CONTRIBUTING.md ├── example.js ├── README.md └── utilities.js /.gitattributes: -------------------------------------------------------------------------------- 1 | * -text 2 | -------------------------------------------------------------------------------- /.eslintignore: -------------------------------------------------------------------------------- 1 | node_modules/ 2 | -------------------------------------------------------------------------------- /.github/FUNDING.yml: -------------------------------------------------------------------------------- 1 | patreon: tshemsedinov 2 | -------------------------------------------------------------------------------- /.gitignore: -------------------------------------------------------------------------------- 1 | node_modules 2 | *.log 3 | .DS_Store 4 | -------------------------------------------------------------------------------- /.npmignore: -------------------------------------------------------------------------------- 1 | node_modules 2 | *.log 3 | .DS_Store 4 | -------------------------------------------------------------------------------- /.prettierrc: -------------------------------------------------------------------------------- 1 | { 2 | "singleQuote": true, 3 | "trailingComma": "es5", 4 | "overrides": [ 5 | { 6 | "files": ".prettierrc", 7 | "options": { "parser": "json" } 8 | } 9 | ], 10 | "arrowParens": "avoid" 11 | } 12 | -------------------------------------------------------------------------------- /.editorconfig: -------------------------------------------------------------------------------- 1 | # http://editorconfig.org 2 | root = true 3 | 4 | [*] 5 | end_of_line = lf 6 | charset = utf-8 7 | insert_final_newline = true 8 | trim_trailing_whitespace = true 9 | 10 | [{*.js,*.mjs,*.ts,*.json,*.yml}] 11 | indent_size = 2 12 | indent_style = space 13 | -------------------------------------------------------------------------------- /.github/PULL_REQUEST_TEMPLATE.md: -------------------------------------------------------------------------------- 1 | 6 | 7 | - [ ] tests and linter show no problems (`npm t`) 8 | - [ ] tests are added/updated for bug fixes and new features 9 | - [ ] code is properly formatted (`npm run fmt`) 10 | -------------------------------------------------------------------------------- /.eslintrc.json: -------------------------------------------------------------------------------- 1 | { 2 | "extends": ["metarhia", "plugin:prettier/recommended"], 3 | "env": { 4 | "browser": true, 5 | "es6": true, 6 | "node": true 7 | }, 8 | "parserOptions": { 9 | "ecmaVersion": 2020 10 | }, 11 | "rules": { 12 | "arrow-parens": "off", 13 | "comma-dangle": "off", 14 | "handle-callback-err": "off", 15 | "consistent-return": "off", 16 | "no-invalid-this": "off" 17 | } 18 | } 19 | -------------------------------------------------------------------------------- /SECURITY.md: -------------------------------------------------------------------------------- 1 | # Security Policy 2 | 3 | ## Supported Versions 4 | 5 | | Version | Supported | 6 | | ------- | ------------------ | 7 | | 0.x | :x: | 8 | | 1.0.x | :x: | 9 | | 1.1.x | :white_check_mark: | 10 | 11 | ## Reporting a Vulnerability 12 | 13 | If you believe you have found a security vulnerability, let us know by sending 14 | email to [timur.shemsedinov@gmail.com](mailto:timur.shemsedinov@gmail.com) 15 | We will investigate that and do our best to quickly fix the problem. 16 | 17 | Please don't open an issue to or discuss this security vulnerability in a public 18 | place. Thanks for understanding! 19 | -------------------------------------------------------------------------------- /.github/ISSUE_TEMPLATE/feature_request.md: -------------------------------------------------------------------------------- 1 | --- 2 | name: Feature request 3 | about: Suggest an idea for this project 4 | title: '' 5 | labels: '' 6 | assignees: '' 7 | --- 8 | 9 | **Is your feature request related to a problem? Please describe.** 10 | A clear and concise description of what the problem is. Ex. I'm always frustrated when [...] 11 | 12 | **Describe the solution you'd like** 13 | A clear and concise description of what you want to happen. 14 | 15 | **Describe alternatives you've considered** 16 | A clear and concise description of any alternative solutions or features you've considered. 17 | 18 | **Additional context** 19 | Add any other context or screenshots about the feature request here. 20 | -------------------------------------------------------------------------------- /.github/ISSUE_TEMPLATE/bug_report.md: -------------------------------------------------------------------------------- 1 | --- 2 | name: Bug report 3 | about: Create a report to help us improve 4 | title: '' 5 | labels: bug 6 | assignees: '' 7 | --- 8 | 9 | **Describe the bug** 10 | A clear and concise description of what the bug is. 11 | 12 | **To Reproduce** 13 | Steps to reproduce the behavior: usage example or test. 14 | 15 | **Expected behavior** 16 | A clear and concise description of what you expected. 17 | 18 | **Screenshots** 19 | If applicable, add screenshots to help explain your problem. 20 | 21 | **Desktop (please complete the following information):** 22 | 23 | - OS: [e.g. Fedora 30 64-bit] 24 | - Node.js version [e.g. 14.15.1] 25 | - MySQL version 26 | 27 | **Additional context** 28 | Add any other context about the problem here. 29 | -------------------------------------------------------------------------------- /.github/workflows/test.yml: -------------------------------------------------------------------------------- 1 | name: Testing CI 2 | 3 | on: pull_request 4 | 5 | jobs: 6 | build: 7 | runs-on: ${{ matrix.os }} 8 | 9 | strategy: 10 | matrix: 11 | node: 12 | - 14 13 | - 16 14 | - 18 15 | - 19 16 | os: 17 | - ubuntu-latest 18 | - windows-latest 19 | - macos-latest 20 | 21 | steps: 22 | - uses: actions/checkout@v2 23 | - name: Use Node.js ${{ matrix.node }} 24 | uses: actions/setup-node@v1 25 | with: 26 | node-version: ${{ matrix.node }} 27 | - uses: actions/cache@v2 28 | with: 29 | path: ~/.npm 30 | key: ${{ runner.os }}-node-${{ hashFiles('**/package-lock.json') }} 31 | restore-keys: | 32 | ${{ runner.os }}-node- 33 | - run: npm ci 34 | - run: npm test 35 | -------------------------------------------------------------------------------- /LICENSE: -------------------------------------------------------------------------------- 1 | MIT License 2 | 3 | Copyright (c) 2013-2023 Impress Application Server contributors 4 | 5 | Permission is hereby granted, free of charge, to any person obtaining a copy 6 | of this software and associated documentation files (the "Software"), to deal 7 | in the Software without restriction, including without limitation the rights 8 | to use, copy, modify, merge, publish, distribute, sublicense, and/or sell 9 | copies of the Software, and to permit persons to whom the Software is 10 | furnished to do so, subject to the following conditions: 11 | 12 | The above copyright notice and this permission notice shall be included in all 13 | copies or substantial portions of the Software. 14 | 15 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR 16 | IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, 17 | FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE 18 | AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER 19 | LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, 20 | OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE 21 | SOFTWARE. 22 | -------------------------------------------------------------------------------- /package.json: -------------------------------------------------------------------------------- 1 | { 2 | "name": "mysql-utilities", 3 | "version": "1.1.5", 4 | "author": "Timur Shemsedinov ", 5 | "description": "Utilities for node-mysql driver with specialized result types, introspection and other helpful functionality.", 6 | "license": "MIT", 7 | "keywords": [ 8 | "mysql", 9 | "utilities", 10 | "introspection", 11 | "impress" 12 | ], 13 | "readmeFilename": "README.md", 14 | "repository": { 15 | "type": "git", 16 | "url": "https://github.com/tshemsedinov/node-mysql-utilities" 17 | }, 18 | "main": "utilities.js", 19 | "files": [], 20 | "scripts": { 21 | "test": "npm run lint && node example", 22 | "lint": "eslint . && prettier -c \"**/*.js\" \"**/*.json\" \"**/*.md\" \"**/*.yml\"", 23 | "fmt": "prettier --write \"**/*.js\" \"**/*.json\" \"**/*.md\" \"**/*.yml\"" 24 | }, 25 | "engines": { 26 | "node": ">= 6.0.0" 27 | }, 28 | "dependencies": { 29 | "mysql": "^2.18.1" 30 | }, 31 | "devDependencies": { 32 | "eslint": "^8.34.0", 33 | "eslint-config-metarhia": "^8.1.0", 34 | "eslint-config-prettier": "^8.6.0", 35 | "eslint-plugin-import": "^2.27.5", 36 | "eslint-plugin-prettier": "^4.2.1", 37 | "prettier": "^2.8.4" 38 | } 39 | } 40 | -------------------------------------------------------------------------------- /CONTRIBUTING.md: -------------------------------------------------------------------------------- 1 | # Contributing 2 | 3 | - [Issues](#issues) 4 | - [Pull Requests](#pull-requests) 5 | 6 | ## Issues 7 | 8 | There are two reasons to open an issue: 9 | 10 | - Bug report 11 | - Feature request 12 | 13 | For bug reports please describe the bug with a clear and concise description, 14 | steps to reproduce the behavior (usage example or test), expected behavior, 15 | provide OS and Node.js version, you can upload screenshots and any additional 16 | context for better understanding. 17 | 18 | Please don't open an issue to ask questions. 19 | 20 | Issues on GitHub are intended to be related to problems and feature requests 21 | so we recommend not using this medium to ask them here grin. Thanks for 22 | understanding! 23 | 24 | If you have a question, please check out our support groups and channels for 25 | developers community: 26 | 27 | Telegram: 28 | 29 | - Channel for Metarhia community: https://t.me/metarhia 30 | - Group for Metarhia technology stack community: https://t.me/metaserverless 31 | - Group for NodeUA community: https://t.me/nodeua 32 | 33 | ## Pull Requests 34 | 35 | Before open pull request please follow checklist: 36 | 37 | - [ ] tests and linter show no problems (`npm t`) 38 | - [ ] tests are added/updated for bug fixes and new features 39 | - [ ] code is properly formatted (`npm run fmt`) 40 | -------------------------------------------------------------------------------- /example.js: -------------------------------------------------------------------------------- 1 | 'use strict'; 2 | 3 | const mysql = require('mysql'); 4 | const mysqlUtilities = require('./utilities'); 5 | 6 | const connection = mysql.createConnection({ 7 | host: 'localhost', 8 | user: 'travis', 9 | password: '', 10 | database: 'db', 11 | }); 12 | 13 | connection.connect(); 14 | 15 | mysqlUtilities.upgrade(connection); 16 | mysqlUtilities.introspection(connection); 17 | 18 | connection.slowTime = 100; // ms 19 | 20 | connection.on('query', (err, res, fields, query) => { 21 | console.dir({ onQuery: { err, query: query.sql } }); 22 | }); 23 | 24 | connection.on('slow', (err, res, fields, query, executionTime) => { 25 | console.dir({ 26 | onSlow: { err, executionTime, query: query.sql }, 27 | }); 28 | }); 29 | 30 | console.log({ 31 | where: connection.where({ 32 | id: 5, 33 | year: '>2010', 34 | price: '100..200', 35 | level: '<=3', 36 | sn: '*str?', 37 | label: 'str', 38 | code: '(1,2,4,10,11)', 39 | }), 40 | }); 41 | 42 | connection.select('_Language', '*', { LanguageId: '1..3' }, (err, results) => { 43 | console.dir({ select: results, err }); 44 | }); 45 | 46 | connection.insert( 47 | '_Language', 48 | { 49 | LanguageName: 'Uygurian', 50 | LanguageSign: 'UY', 51 | LanguageISO: 'UY', 52 | Caption: 'Uygurian', 53 | }, 54 | (err, results) => { 55 | console.dir({ insert: results, err }); 56 | } 57 | ); 58 | 59 | connection.update( 60 | '_Language', 61 | { 62 | LanguageId: 1, 63 | LanguageName: 'Qwertian', 64 | LanguageSign: 'QW', 65 | LanguageISO: 'QW', 66 | Caption: 'Qwertian', 67 | }, 68 | (err, results) => { 69 | console.dir({ update: results, err }); 70 | } 71 | ); 72 | 73 | connection.update( 74 | '_Language', 75 | { LanguageName: 'QwertianA', LanguageSign: 'QA' }, 76 | { LanguageId: 1 }, 77 | (err, results) => { 78 | console.dir({ update: results, err }); 79 | } 80 | ); 81 | 82 | connection.upsert( 83 | '_Language', 84 | { 85 | LanguageId: 1, 86 | LanguageName: 'Qwertianian', 87 | LanguageSign: 'QW', 88 | LanguageISO: 'QW', 89 | Caption: 'Qwertianian', 90 | }, 91 | (err, results) => { 92 | console.dir({ upsert: results, err }); 93 | } 94 | ); 95 | 96 | connection.delete('_Language', { LanguageSign: 'UY' }, (err, results) => { 97 | console.dir({ delete: results, err }); 98 | }); 99 | 100 | connection.query( 101 | 'SELECT * FROM _Language where LanguageId > ?', 102 | [2], 103 | (err, results) => { 104 | console.dir({ query: results }); 105 | } 106 | ); 107 | 108 | connection.queryRow( 109 | 'SELECT * FROM _Language where LanguageId = ?', 110 | [3], 111 | (err, row) => { 112 | console.dir({ queryRow: row }); 113 | } 114 | ); 115 | 116 | connection.queryValue( 117 | 'SELECT LanguageName FROM _Language where LanguageId = ?', 118 | [8], 119 | (err, name) => { 120 | console.dir({ queryValue: name }); 121 | } 122 | ); 123 | 124 | connection.queryHash( 125 | 'SELECT LanguageSign, LanguageId, LanguageName, Caption, LanguageISO ' + 126 | 'FROM _Language', 127 | [], 128 | (err, arr) => { 129 | console.dir({ queryHash: arr }); 130 | } 131 | ); 132 | 133 | connection.queryCol('SELECT LanguageSign FROM _Language', [], (err, arr) => { 134 | console.dir({ queryCol: arr }); 135 | }); 136 | 137 | connection.queryKeyValue( 138 | 'SELECT LanguageISO, LanguageName FROM _Language', 139 | [], 140 | (err, keyValue) => { 141 | console.dir({ queryKeyValue: keyValue }); 142 | } 143 | ); 144 | 145 | connection.count('_Language', { LanguageId: '>3' }, (err, count) => { 146 | console.dir({ count }); 147 | }); 148 | 149 | connection.primary('_Language', (err, primary) => { 150 | console.dir({ primary }); 151 | }); 152 | 153 | connection.foreign('_TemplateCaption', (err, foreign) => { 154 | console.dir({ foreign }); 155 | }); 156 | 157 | connection.constraints('_TemplateCaption', (err, constraints) => { 158 | console.dir({ constraints }); 159 | }); 160 | 161 | connection.fields('_Language', (err, fields) => { 162 | console.dir({ fields }); 163 | }); 164 | 165 | connection.databases((err, databases) => { 166 | console.dir({ databases }); 167 | }); 168 | 169 | connection.tables((err, tables) => { 170 | console.dir({ tables }); 171 | }); 172 | 173 | connection.databaseTables('mezha', (err, tables) => { 174 | console.dir({ tables }); 175 | }); 176 | 177 | connection.tableInfo('_Language', (err, info) => { 178 | console.dir({ tableInfo: info }); 179 | }); 180 | 181 | connection.indexes('_Language', (err, indexes) => { 182 | console.dir({ indexes }); 183 | }); 184 | 185 | connection.processes((err, processes) => { 186 | console.dir({ processes }); 187 | }); 188 | 189 | connection.globalVariables((err, globalVariables) => { 190 | console.dir({ globalVariables }); 191 | }); 192 | 193 | connection.globalStatus((err, globalStatus) => { 194 | console.dir({ globalStatus }); 195 | }); 196 | 197 | connection.users((err, users) => { 198 | console.dir({ users }); 199 | }); 200 | 201 | setTimeout(() => { 202 | connection.end(); 203 | }, 2000); 204 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # Node MySql Utilities 2 | 3 | [Utilities](https://github.com/tshemsedinov/node-mysql-utilities) for 4 | [node-mysql driver](https://github.com/felixge/node-mysql) with specialized 5 | result types, introspection and other helpful functionality for 6 | [node.js](http://nodejs.org). Initially this utilities were part of 7 | [Impress](https://npmjs.org/package/impress) Application Server and 8 | extracted separately for use with other frameworks. 9 | 10 | [![CI Status](https://github.com/tshemsedinov/node-mysql-utilities/workflows/Testing%20CI/badge.svg)](https://github.com/tshemsedinov/node-mysql-utilities/actions?query=workflow%3A%22Testing+CI%22+branch%3Amaster) 11 | [![NPM Version](https://badge.fury.io/js/mysql-utilities.svg)](https://badge.fury.io/js/mysql-utilities) 12 | [![NPM Downloads/Month](https://img.shields.io/npm/dm/mysql-utilities.svg)](https://www.npmjs.com/package/mysql-utilities) 13 | [![NPM Downloads](https://img.shields.io/npm/dt/mysql-utilities.svg)](https://www.npmjs.com/package/mysql-utilities) 14 | 15 | ![impress logo](http://habrastorage.org/storage3/747/830/b17/747830b1782bd95f28b8d05eff8e05d9.jpg) 16 | 17 | ## Installation 18 | 19 | ```bash 20 | $ npm install mysql-utilities 21 | ``` 22 | 23 | ## Features 24 | 25 | - MySQL Data Access Methods 26 | - Query selecting single row: connection.queryRow(sql, values, callback) 27 | - Query selecting scalar (single value): connection.queryValue(sql, values, callback) 28 | - Query selecting column into array: connection.queryCol(sql, values, callback) 29 | - Query selecting hash of records: connection.queryHash(sql, values, callback) 30 | - Query selecting key/value hash: connection.queryKeyValue(sql, values, callback) 31 | - MySQL Introspection Methods 32 | - Get primary key metadata: connection.primary(table, callback) 33 | - Get foreign key metadata: connection.foreign(table, callback) 34 | - Get table constraints metadata: connection.constraints(table, callback) 35 | - Get table fields metadata: connection.fields(table, callback) 36 | - Get connection databases array: connection.databases(callback) 37 | - Get database tables list for current db: connection.tables(callback) 38 | - Get database tables list for given db: connection.databaseTables(database, callback) 39 | - Get table metadata: connection.tableInfo(table, callback) 40 | - Get table indexes metadata: connection.indexes(table, callback) 41 | - Get server process list: connection.processes(callback) 42 | - Get server global variables: connection.globalVariables(callback) 43 | - Get server global status: connection.globalStatus(callback) 44 | - Get database users: connection.users(callback) 45 | - MySQL SQL Statements Autogenerating Methods 46 | - Selecting record(s): connection.select(table, whereFilter, callback) 47 | - Inserting record: connection.insert(table, row, callback) 48 | - Updating record: connection.update(table, row, where, callback) 49 | - Inserting or selecting record: connection.upsert(table, row, callback) 50 | - Count records with filter: connection.count(table, whereFilter, callback) 51 | - Delete record(s): connection.delete(table, whereFilter, callback) 52 | - Events 53 | - Catch any query execution: connection.on('query', function(err, res, fields, query) {}); 54 | - Catch errors: connection.on('error', function(err, query) {}); 55 | - Catch slow query execution: connection.on('slow', function(err, res, fields, query, executionTime) {}); 56 | 57 | ## Initialization 58 | 59 | Utilities can be attached to connection using mix-ins: 60 | 61 | ```js 62 | // Library dependencies 63 | const mysql = require('mysql'); 64 | const mysqlUtilities = require('mysql-utilities'); 65 | 66 | const connection = mysql.createConnection({ 67 | host: 'localhost', 68 | user: 'userName', 69 | password: 'secret', 70 | database: 'databaseName', 71 | }); 72 | 73 | connection.connect(); 74 | 75 | // Mix-in for Data Access Methods and SQL Autogenerating Methods 76 | mysqlUtilities.upgrade(connection); 77 | 78 | // Mix-in for Introspection Methods 79 | mysqlUtilities.introspection(connection); 80 | 81 | // Do something using utilities 82 | connection.queryRow( 83 | 'SELECT * FROM _Language where LanguageId=?', 84 | [3], 85 | (err, row) => { 86 | console.dir({ queryRow: row }); 87 | } 88 | ); 89 | 90 | // Release connection 91 | connection.end(); 92 | ``` 93 | 94 | ## Examples 95 | 96 | Single row selection: connection.queryRow(sql, values, callback) returns hash as callback second parameter, field names becomes hash keys. 97 | 98 | ```js 99 | connection.queryRow( 100 | 'SELECT * FROM Language where LanguageId=?', 101 | [3], 102 | (err, row) => { 103 | console.dir({ queryRow: row }); 104 | } 105 | ); 106 | ``` 107 | 108 | Output: 109 | 110 | ```js 111 | queryRow: { 112 | LanguageId: 3, 113 | LanguageName: 'Russian', 114 | LanguageSign: 'ru', 115 | LanguageISO: 'ru', 116 | Caption: 'Русский' 117 | } 118 | ``` 119 | 120 | Single value selection: connection.queryValue(sql, values, callback) returns single value as callback second parameter (instead of array in array). For example, for Id selection by name with LIMIT 1 or count(\*), max(field) etc. 121 | 122 | ```js 123 | connection.queryValue( 124 | 'SELECT LanguageName FROM Language where LanguageId=?', 125 | [8], 126 | (err, name) => { 127 | console.dir({ queryValue: name }); 128 | } 129 | ); 130 | ``` 131 | 132 | Output: 133 | 134 | ```js 135 | { 136 | queryValue: 'Italiano'; 137 | } 138 | ``` 139 | 140 | Single column selection: connection.queryCol(sql, values, callback) returns array as callback second parameter. 141 | 142 | ```js 143 | connection.queryCol('SELECT LanguageSign FROM Language', [], (err, result) => { 144 | console.dir({ queryCal: result }); 145 | }); 146 | ``` 147 | 148 | Output: 149 | 150 | ```js 151 | queryArray: ['de', 'en', 'es', 'fr', 'it', 'pl', 'ru', 'ua']; 152 | ``` 153 | 154 | Hash selection: connection.queryHash(sql, values, callback) returns hash as callback second parameter, hash keyed by first field values from SQL statement. 155 | 156 | ```js 157 | connection.queryHash( 158 | 'SELECT LanguageSign, LanguageId, LanguageName, Caption, LanguageISO FROM Language', 159 | [], 160 | (err, result) => { 161 | console.dir({ queryHash: result }); 162 | } 163 | ); 164 | ``` 165 | 166 | Output: 167 | 168 | ```js 169 | queryHash: { 170 | en: { 171 | LanguageSign: 'en', 172 | LanguageId: 2, 173 | LanguageName: 'English', 174 | Caption: 'Английский', 175 | LanguageISO: 'en' }, 176 | ru: { 177 | LanguageSign: 'ru', 178 | LanguageId: 3, 179 | LanguageName: 'Russian', 180 | Caption: 'Русский', 181 | LanguageISO: 'ru' }, 182 | de: { 183 | LanguageSign: 'de', 184 | LanguageId: 7, 185 | LanguageName: 'Deutsch', 186 | Caption: 'Немецкий', 187 | LanguageISO: 'de' }, 188 | it: { 189 | LanguageSign: 'it', 190 | LanguageId: 8, 191 | LanguageName: 'Italiano', 192 | Caption: 'Итальянский', 193 | LanguageISO: 'it' 194 | } 195 | } 196 | ``` 197 | 198 | Key/value pair selection: connection.queryKeyValue(sql, values, callback) returns hash as callback second parameter, hash keyed by first field, values filled by second field. 199 | 200 | ```js 201 | connection.queryKeyValue( 202 | 'SELECT LanguageISO, LanguageName FROM Language', 203 | [], 204 | (err, keyValue) => { 205 | console.dir({ queryKeyValue: keyValue }); 206 | } 207 | ); 208 | ``` 209 | 210 | Output: 211 | 212 | ```js 213 | keyValue: { 214 | en: 'English', 215 | ru: 'Russian', 216 | uk: 'Ukrainian', 217 | es: 'Espanol', 218 | fr: 'Francais', 219 | de: 'Deutsch', 220 | it: 'Italiano', 221 | pl: 'Poliski' 222 | } 223 | ``` 224 | 225 | Get primary key list with metadata: connection.primary(table, callback) returns metadata as callback second parameter. 226 | 227 | ```js 228 | connection.primary('Language', (err, primary) => { 229 | console.dir({ primary }); 230 | }); 231 | ``` 232 | 233 | Output: 234 | 235 | ```js 236 | primary: { 237 | Table: 'language', 238 | Non_unique: 0, 239 | Key_name: 'PRIMARY', 240 | Seq_in_index: 1, 241 | Column_name: 'LanguageId', 242 | Collation: 'A', 243 | Cardinality: 9, 244 | Sub_part: null, 245 | Packed: null, 246 | Null: '', 247 | Index_type: 'BTREE', 248 | Comment: '', 249 | Index_comment: '' 250 | } 251 | ``` 252 | 253 | Get foreign key list with metadata: connection.foreign(table, callback) returns metadata as callback second parameter. 254 | 255 | ```js 256 | connection.foreign('TemplateCaption', (err, foreign) => { 257 | console.dir({ foreign }); 258 | }); 259 | ``` 260 | 261 | Output: 262 | 263 | ```js 264 | foreign: { 265 | fkTemplateCaptionLanguage: { 266 | CONSTRAINT_NAME: 'fkTemplateCaptionLanguage', 267 | COLUMN_NAME: 'LanguageId', 268 | ORDINAL_POSITION: 1, 269 | POSITION_IN_UNIQUE_CONSTRAINT: 1, 270 | REFERENCED_TABLE_NAME: 'language', 271 | REFERENCED_COLUMN_NAME: 'LanguageId' }, 272 | fkTemplateCaptionTemplate: { 273 | CONSTRAINT_NAME: 'fkTemplateCaptionTemplate', 274 | COLUMN_NAME: 'TemplateId', 275 | ORDINAL_POSITION: 1, 276 | POSITION_IN_UNIQUE_CONSTRAINT: 1, 277 | REFERENCED_TABLE_NAME: 'template', 278 | REFERENCED_COLUMN_NAME: 'TemplateId' 279 | } 280 | } 281 | ``` 282 | 283 | Referential constraints list with metadata: connection.constraints(table, callback). 284 | 285 | ```js 286 | connection.constraints('TemplateCaption', (err, constraints) => { 287 | console.dir({ constraints }); 288 | }); 289 | ``` 290 | 291 | Output: 292 | 293 | ```js 294 | constraints: { 295 | fkTemplateCaptionLanguage: { 296 | CONSTRAINT_NAME: 'fkTemplateCaptionLanguage', 297 | UNIQUE_CONSTRAINT_NAME: 'PRIMARY', 298 | REFERENCED_TABLE_NAME: 'Language', 299 | MATCH_OPTION: 'NONE', 300 | UPDATE_RULE: 'RESTRICT', 301 | DELETE_RULE: 'CASCADE' }, 302 | fkTemplateCaptionTemplate: { 303 | CONSTRAINT_NAME: 'fkTemplateCaptionTemplate', 304 | UNIQUE_CONSTRAINT_NAME: 'PRIMARY', 305 | REFERENCED_TABLE_NAME: 'Template', 306 | MATCH_OPTION: 'NONE', 307 | UPDATE_RULE: 'RESTRICT', 308 | DELETE_RULE: 'CASCADE' 309 | } 310 | } 311 | ``` 312 | 313 | Get table fields with metadata: connection.fields(table, callback). 314 | 315 | ```js 316 | connection.fields('Language', (err, fields) => { 317 | console.dir({ fields }); 318 | }); 319 | ``` 320 | 321 | Output: 322 | 323 | ```js 324 | fields: { 325 | LanguageId: { 326 | Field: 'LanguageId', 327 | Type: 'int(10) unsigned', 328 | Collation: null, 329 | Null: 'NO', 330 | Key: 'PRI', 331 | Default: null, 332 | Extra: 'auto_increment', 333 | Privileges: 'select,insert,update,references', 334 | Comment: 'Id(EN),Код(RU)' }, 335 | LanguageName: { 336 | Field: 'LanguageName', 337 | Type: 'varchar(32)', 338 | Collation: 'utf8_general_ci', 339 | Null: 'NO', 340 | Key: 'UNI', 341 | Default: null, 342 | Extra: '', 343 | Privileges: 'select,insert,update,references', 344 | Comment: 'Name(EN),Имя(RU)' 345 | }, ... 346 | } 347 | ``` 348 | 349 | Get database list for current connection: connection.databases(callback). 350 | 351 | ```js 352 | connection.databases((err, databases) => { 353 | console.dir({ databases }); 354 | }); 355 | ``` 356 | 357 | Output: 358 | 359 | ```js 360 | databases: [ 361 | 'information_schema', 362 | 'mezha', 363 | 'mysql', 364 | 'performance_schema', 365 | 'test', 366 | ]; 367 | ``` 368 | 369 | Get table list for current database: connection.tables(callback). 370 | 371 | ```js 372 | connection.tables((err, tables) => { 373 | console.dir({ tables }); 374 | }); 375 | ``` 376 | 377 | Output: 378 | 379 | ```js 380 | tables: { 381 | Language: { 382 | TABLE_NAME: 'Language', 383 | TABLE_TYPE: 'BASE TABLE', 384 | ENGINE: 'InnoDB', 385 | VERSION: 10, 386 | ROW_FORMAT: 'Compact', 387 | TABLE_ROWS: 9, 388 | AVG_ROW_LENGTH: 1820, 389 | DATA_LENGTH: 16384, 390 | MAX_DATA_LENGTH: 0, 391 | INDEX_LENGTH: 49152, 392 | DATA_FREE: 8388608, 393 | AUTO_INCREMENT: 10, 394 | CREATE_TIME: Mon Jul 15 2013 03:06:08 GMT+0300 (Финляндия (лето)), 395 | UPDATE_TIME: null, 396 | CHECK_TIME: null, 397 | TABLE_COLLATION: 'utf8_general_ci', 398 | CHECKSUM: null, 399 | CREATE_OPTIONS: '', 400 | TABLE_COMMENT: '_Language:Languages(EN),Языки(RU)' 401 | }, ... 402 | } 403 | ``` 404 | 405 | Get table list for specified database: connection.databaseTables(database, callback). 406 | 407 | ```js 408 | connection.databaseTables('databaseName', (err, tables) => { 409 | console.dir({ databaseTables: tables }); 410 | }); 411 | ``` 412 | 413 | Output: 414 | 415 | ```js 416 | tables: { 417 | Language: { 418 | TABLE_NAME: 'Language', 419 | TABLE_TYPE: 'BASE TABLE', 420 | ENGINE: 'InnoDB', 421 | VERSION: 10, 422 | ROW_FORMAT: 'Compact', 423 | TABLE_ROWS: 9, 424 | AVG_ROW_LENGTH: 1820, 425 | DATA_LENGTH: 16384, 426 | MAX_DATA_LENGTH: 0, 427 | INDEX_LENGTH: 49152, 428 | DATA_FREE: 8388608, 429 | AUTO_INCREMENT: 10, 430 | CREATE_TIME: Mon Jul 15 2013 03:06:08 GMT+0300 (Финляндия (лето)), 431 | UPDATE_TIME: null, 432 | CHECK_TIME: null, 433 | TABLE_COLLATION: 'utf8_general_ci', 434 | CHECKSUM: null, 435 | CREATE_OPTIONS: '', 436 | TABLE_COMMENT: '_Language:Languages(EN),Языки(RU)' 437 | }, ... 438 | } 439 | ``` 440 | 441 | Get table metadata: connection.tableInfo(table, callback). 442 | 443 | ```js 444 | connection.tableInfo('Language', (err, info) => { 445 | console.dir({ tableInfo: info }); 446 | }); 447 | ``` 448 | 449 | Output: 450 | 451 | ```js 452 | tableInfo: { 453 | Name: 'language', 454 | Engine: 'InnoDB', 455 | Version: 10, 456 | Row_format: 'Compact', 457 | Rows: 9, 458 | Avg_row_length: 1820, 459 | Data_length: 16384, 460 | Max_data_length: 0, 461 | Index_length: 49152, 462 | Data_free: 9437184, 463 | Auto_increment: 10, 464 | Create_time: Mon Jul 15 2013 03:06:08 GMT+0300 (Финляндия (лето)), 465 | Update_time: null, 466 | Check_time: null, 467 | Collation: 'utf8_general_ci', 468 | Checksum: null, 469 | Create_options: '', 470 | Comment: '' 471 | } 472 | ``` 473 | 474 | Get table indexes metadata: connection.indexes(table, callback). 475 | 476 | ```js 477 | connection.indexes('Language', function (err, info) { 478 | console.dir({ tableInfo: info }); 479 | }); 480 | ``` 481 | 482 | Output: 483 | 484 | ```js 485 | indexes: { 486 | PRIMARY: { 487 | Table: 'language', 488 | Non_unique: 0, 489 | Key_name: 'PRIMARY', 490 | Seq_in_index: 1, 491 | Column_name: 'LanguageId', 492 | Collation: 'A', 493 | Cardinality: 9, 494 | Sub_part: null, 495 | Packed: null, 496 | Null: '', 497 | Index_type: 'BTREE', 498 | Comment: '', 499 | Index_comment: '' }, 500 | akLanguage: { 501 | Table: 'language', 502 | Non_unique: 0, 503 | Key_name: 'akLanguage', 504 | Seq_in_index: 1, 505 | Column_name: 'LanguageName', 506 | Collation: 'A', 507 | Cardinality: 9, 508 | Sub_part: null, 509 | Packed: null, 510 | Null: '', 511 | Index_type: 'BTREE', 512 | Comment: '', 513 | Index_comment: '' 514 | } 515 | } 516 | ``` 517 | 518 | Get MySQL process list: connection.processes(callback). 519 | 520 | ```js 521 | connection.processes(function (err, processes) { 522 | console.dir({ processes }); 523 | }); 524 | ``` 525 | 526 | Output: 527 | 528 | ```js 529 | processes: [ 530 | { 531 | ID: 62, 532 | USER: 'mezha', 533 | HOST: 'localhost:14188', 534 | DB: 'mezha', 535 | COMMAND: 'Query', 536 | TIME: 0, 537 | STATE: 'executing', 538 | INFO: 'SELECT * FROM information_schema.PROCESSLIST', 539 | }, 540 | { 541 | ID: 33, 542 | USER: 'root', 543 | HOST: 'localhost:39589', 544 | DB: null, 545 | COMMAND: 'Sleep', 546 | TIME: 1, 547 | STATE: '', 548 | INFO: null, 549 | }, 550 | ]; 551 | ``` 552 | 553 | Get MySQL global variables: connection.globalVariables(callback) 554 | 555 | ```js 556 | connection.globalVariables((err, globalVariables) => { 557 | console.dir({ globalVariables }); 558 | }); 559 | ``` 560 | 561 | Output: 562 | 563 | ```js 564 | globalVariables: { 565 | MAX_PREPARED_STMT_COUNT: '16382', 566 | MAX_JOIN_SIZE: '18446744073709551615', 567 | HAVE_CRYPT: 'NO', 568 | PERFORMANCE_SCHEMA_EVENTS_WAITS_HISTORY_LONG_SIZE: '10000', 569 | INNODB_VERSION: '5.5.32', 570 | FLUSH_TIME: '1800', 571 | MAX_ERROR_COUNT: '64', 572 | ... 573 | } 574 | ``` 575 | 576 | Get MySQL global status: connection.globalStatus(callback) 577 | 578 | ```js 579 | connection.globalStatus((err, globalStatus) => { 580 | console.dir({ globalStatus }); 581 | }); 582 | ``` 583 | 584 | Output: 585 | 586 | ```js 587 | globalStatus: { 588 | ABORTED_CLIENTS: '54', 589 | ABORTED_CONNECTS: '2', 590 | BINLOG_CACHE_DISK_USE: '0', 591 | BINLOG_CACHE_USE: '0', 592 | BINLOG_STMT_CACHE_DISK_USE: '0', 593 | BINLOG_STMT_CACHE_USE: '0', 594 | BYTES_RECEIVED: '654871', 595 | BYTES_SENT: '212454927', 596 | COM_ADMIN_COMMANDS: '594', 597 | ... 598 | } 599 | ``` 600 | 601 | Get MySQL user list: connection.users(callback) 602 | 603 | ```js 604 | connection.users((err, users) => { 605 | console.dir({ users }); 606 | }); 607 | ``` 608 | 609 | Output: 610 | 611 | ```js 612 | users: [ 613 | { 614 | Host: 'localhost', 615 | User: 'root', 616 | Password: '*90E462C37378CED12064BB3388827D2BA3A9B689', 617 | Select_priv: 'Y', 618 | Insert_priv: 'Y', 619 | Update_priv: 'Y', 620 | Delete_priv: 'Y', 621 | Create_priv: 'Y', 622 | Drop_priv: 'Y', 623 | Reload_priv: 'Y', 624 | Shutdown_priv: 'Y', 625 | Process_priv: 'Y', 626 | File_priv: 'Y', 627 | Grant_priv: 'Y', 628 | References_priv: 'Y', 629 | Index_priv: 'Y', 630 | Alter_priv: 'Y', 631 | Show_db_priv: 'Y', 632 | Super_priv: 'Y', 633 | Create_tmp_table_priv: 'Y', 634 | Lock_tables_priv: 'Y', 635 | Execute_priv: 'Y', 636 | Repl_slave_priv: 'Y', 637 | Repl_client_priv: 'Y', 638 | Create_view_priv: 'Y', 639 | Show_view_priv: 'Y', 640 | Create_routine_priv: 'Y', 641 | Alter_routine_priv: 'Y', 642 | Create_user_priv: 'Y', 643 | Event_priv: 'Y', 644 | Trigger_priv: 'Y', 645 | Create_tablespace_priv: 'Y', 646 | ssl_type: '', 647 | ssl_cipher: , 648 | x509_issuer: , 649 | x509_subject: , 650 | max_questions: 0, 651 | max_updates: 0, 652 | max_connections: 0, 653 | max_user_connections: 0, 654 | plugin: '', 655 | authentication_string: '' 656 | }, ... 657 | ] 658 | ``` 659 | 660 | Generate MySQL WHERE statement: connection.where(conditions), works synchronously, no callback. Returns WHERE statement for given JSON-style conditions. 661 | 662 | ```js 663 | const where = connection.where({ 664 | id: 5, 665 | year: '>2010', 666 | price: '100..200', 667 | level: '<=3', 668 | sn: '*str?', 669 | label: 'str', 670 | code: '(1,2,4,10,11)', 671 | }); 672 | console.dir(where); 673 | // Output: "id = 5 AND year > '2010' AND (price BETWEEN '100' AND '200') AND 674 | // level <= '3' AND sn LIKE '%str_' AND label = 'str' AND code IN (1,2,4,10,11)" 675 | ``` 676 | 677 | Generate SELECT statement: connection.select(table, whereFilter, orderBy, callback) 678 | 679 | ```js 680 | connection.select( 681 | 'Language', 682 | '*', 683 | { LanguageId: '1..3' }, 684 | { LanguageId: 'desc' }, 685 | (err, results) => { 686 | console.dir({ select: results }); 687 | } 688 | ); 689 | ``` 690 | 691 | Generate INSERT statement: connection.insert(table, row, callback) 692 | 693 | ```js 694 | connection.insert( 695 | 'Language', 696 | { 697 | LanguageName: 'Tatar', 698 | LanguageSign: 'TT', 699 | LanguageISO: 'TT', 700 | Caption: 'Tatar', 701 | }, 702 | (err, recordId) => { 703 | console.dir({ insert: recordId }); 704 | } 705 | ); 706 | ``` 707 | 708 | Generate UPDATE statement: connection.update(table, row, callback) 709 | 710 | ```js 711 | connection.update( 712 | 'Language', 713 | { 714 | LanguageId: 25, 715 | LanguageName: 'Tatarca', 716 | LanguageSign: 'TT', 717 | LanguageISO: 'TT', 718 | Caption: 'Tatarca', 719 | }, 720 | (err, affectedRows) => { 721 | console.dir({ update: affectedRows }); 722 | } 723 | ); 724 | ``` 725 | 726 | Generate UPDATE statement with "where": connection.update(table, row, where, callback) 727 | 728 | ```js 729 | connection.update( 730 | 'Language', 731 | { LanguageSign: 'TT' }, 732 | { LanguageId: 1 }, 733 | (err, affectedRows) => { 734 | console.dir({ update: affectedRows }); 735 | } 736 | ); 737 | ``` 738 | 739 | Generate INSERT statement if record not exists or UPDATE if it exists: connection.upsert(table, row, callback) 740 | 741 | ```js 742 | connection.upsert( 743 | 'Language', 744 | { 745 | LanguageId: 25, 746 | LanguageName: 'Tatarca', 747 | LanguageSign: 'TT', 748 | LanguageISO: 'TT', 749 | Caption: 'Tatarca', 750 | }, 751 | (err, affectedRows) => { 752 | console.dir({ upsert: affectedRows }); 753 | } 754 | ); 755 | ``` 756 | 757 | Get record count: connection.count(table, whereFilter, callback) 758 | 759 | ```js 760 | connection.count('Language', { LanguageId: '>3' }, (err, count) => { 761 | console.dir({ count }); 762 | // count: 9 763 | }); 764 | ``` 765 | 766 | Generate DELETE statement: connection.delete(table, whereFilter, callback) 767 | 768 | ```js 769 | connection.delete('Language', { LanguageSign: 'TT' }, (err, affectedRows) => { 770 | console.dir({ delete: affectedRows }); 771 | }); 772 | ``` 773 | 774 | ## License & Contributors 775 | 776 | Copyright (c) 2012-2023 Metarhia <timur.shemsedinov@gmail.com> 777 | See github for full [contributors list](https://github.com/tshemsedinov/node-mysql-utilities/graphs/contributors). 778 | Node MySql Utilities is [MIT licensed](./LICENSE). 779 | -------------------------------------------------------------------------------- /utilities.js: -------------------------------------------------------------------------------- 1 | 'use strict'; 2 | 3 | const identifierRegexp = /^[0-9,a-z,A-Z_.]*$/; 4 | 5 | const escapeIdentifier = (str, quote) => { 6 | quote = quote || '`'; 7 | if (identifierRegexp.test(str)) return str; 8 | return quote + str + quote; 9 | }; 10 | 11 | if (typeof Function.prototype.override !== 'function') { 12 | Function.prototype.override = function (fn) { 13 | const superFunction = this; 14 | return function (...args) { 15 | this.inherited = superFunction; 16 | return fn.apply(this, args); 17 | }; 18 | }; 19 | } 20 | 21 | const buildCondition = (key, value, esc) => { 22 | for (const operator of ['>=', '<=', '<>', '>', '<']) { 23 | if (value.startsWith(operator)) { 24 | const s = value.substring(operator.length); 25 | return `${key} ${operator} ${esc(s)}`; 26 | } 27 | } 28 | if (value.startsWith('(')) { 29 | const list = value.substr(1, value.length - 2).split(','); 30 | const set = list.map(s => esc(s)).join(','); 31 | return `${key} IN (${set})`; 32 | } 33 | if (value.includes('..')) { 34 | const [begin, end] = value.split('..'); 35 | return `(${key} BETWEEN ${begin} AND ${end})`; 36 | } 37 | if (value.includes('*') || value.includes('?')) { 38 | const val = value.replace(/\*/g, '%').replace(/\?/g, '_'); 39 | return `${key} LIKE ${esc(val)}`; 40 | } 41 | return `${key} = ${esc(value)}`; 42 | }; 43 | 44 | const upgrade = connection => { 45 | if (!connection._mixedUpgrade) { 46 | connection._mixedUpgrade = true; 47 | connection.slowTime = 2000; 48 | 49 | connection.query = connection.query.override(function ( 50 | sql, 51 | values, 52 | callback 53 | ) { 54 | const startTime = new Date().getTime(); 55 | if (typeof values === 'function') { 56 | callback = values; 57 | values = []; 58 | } 59 | const query = this.inherited(sql, values, (err, res, fields) => { 60 | const endTime = new Date().getTime(); 61 | const executionTime = endTime - startTime; 62 | connection.emit('query', err, res, fields, query); 63 | if (connection.slowTime && executionTime >= connection.slowTime) { 64 | connection.emit('slow', err, res, fields, query, executionTime); 65 | } 66 | if (callback) callback(err, res, fields); 67 | }); 68 | return query; 69 | }); 70 | 71 | // Where clause builder 72 | // Example: { 73 | // id: 5, year: '>2010', price: '100..200', 74 | // level: '<=3', sn: '*str?', label: 'str', 75 | // code: '(1,2,4,10,11)' } 76 | // Returns: 'id = 5 AND year > '2010' AND (price BETWEEN '100' AND '200') 77 | // AND level <= '3' AND sn LIKE '%str_' 78 | // AND label = 'str' AND code IN (1,2,4,10,11)' 79 | // 80 | connection.where = function (where) { 81 | const result = []; 82 | for (const key in where) { 83 | const value = where[key]; 84 | if (typeof value === 'number') { 85 | result.push(`${key} = ${value.toString()}`); 86 | } else if (typeof value === 'string') { 87 | result.push(buildCondition(key, value, s => this.escape(s))); 88 | } 89 | } 90 | return result.join(' AND '); 91 | }; 92 | 93 | // Order builder 94 | // Example: { id: 'asc', name: 'desc' } 95 | // Returns: 'id asc, name desc' 96 | // 97 | connection.order = function (order) { 98 | const result = []; 99 | let key, val, clause; 100 | for (key in order) { 101 | val = order[key]; 102 | clause = key; 103 | result.push(clause + ' ' + val); 104 | } 105 | if (result.length) return result.join(); 106 | return ''; 107 | }; 108 | 109 | // Record count 110 | // 111 | connection.count = function (table, where, callback) { 112 | where = this.where(where); 113 | let sql = 'SELECT count(*) FROM ' + escapeIdentifier(table); 114 | if (where) sql = sql + ' WHERE ' + where; 115 | return this.queryValue(sql, [], (err, res) => { 116 | callback(err, res); 117 | }); 118 | }; 119 | 120 | // Returns single row as associative array of fields 121 | // 122 | connection.queryRow = function (sql, values, callback) { 123 | if (typeof values === 'function') { 124 | callback = values; 125 | values = []; 126 | } 127 | return this.query(sql, values, (err, res, fields) => { 128 | if (err) return callback(err); 129 | res = res[0] ? res[0] : false; 130 | callback(err, res, fields); 131 | }); 132 | }; 133 | 134 | // Returns single value (scalar) 135 | // 136 | connection.queryValue = function (sql, values, callback) { 137 | if (typeof values === 'function') { 138 | callback = values; 139 | values = []; 140 | } 141 | return this.queryRow(sql, values, (err, res, fields) => { 142 | if (err) return callback(err); 143 | const value = res[Object.keys(res)[0]]; 144 | callback(err, value, fields); 145 | }); 146 | }; 147 | 148 | // Query returning array of column field values 149 | // 150 | connection.queryCol = function (sql, values, callback) { 151 | if (typeof values === 'function') { 152 | callback = values; 153 | values = []; 154 | } 155 | return this.query(sql, values, (err, res, fields) => { 156 | if (err) return callback(err); 157 | const result = []; 158 | let i, row, keys; 159 | for (i in res) { 160 | row = res[i]; 161 | keys = Object.keys(row); 162 | result.push(row[keys[0]]); 163 | } 164 | callback(err, result, fields); 165 | }); 166 | }; 167 | 168 | // Query returning hash (associative array), first field will be array key 169 | // 170 | connection.queryHash = function (sql, values, callback) { 171 | if (typeof values === 'function') { 172 | callback = values; 173 | values = []; 174 | } 175 | return this.query(sql, values, (err, res, fields) => { 176 | if (err) return callback(err); 177 | const result = {}; 178 | let i, row, keys; 179 | for (i in res) { 180 | row = res[i]; 181 | keys = Object.keys(row); 182 | result[row[keys[0]]] = row; 183 | } 184 | callback(err, result, fields); 185 | }); 186 | }; 187 | 188 | // Query returning key-value array, 189 | // first field of query will be key and second will be value 190 | // 191 | connection.queryKeyValue = function (sql, values, callback) { 192 | if (typeof values === 'function') { 193 | callback = values; 194 | values = []; 195 | } 196 | return this.query(sql, values, (err, res, fields) => { 197 | if (err) return callback(err); 198 | const result = {}; 199 | let i, row, keys; 200 | for (i in res) { 201 | row = res[i]; 202 | keys = Object.keys(row); 203 | result[row[keys[0]]] = row[keys[1]]; 204 | } 205 | callback(err, result, fields); 206 | }); 207 | }; 208 | 209 | // SELECT SQL statement generator 210 | // 211 | connection.select = function (table, fields, where, order, callback) { 212 | where = this.where(where); 213 | if (typeof order === 'function') { 214 | callback = order; 215 | order = {}; 216 | } 217 | order = this.order(order); 218 | let sql = 'SELECT ' + fields + ' FROM ' + escapeIdentifier(table); 219 | if (where) sql = sql + ' WHERE ' + where; 220 | if (order) sql = sql + ' ORDER BY ' + order; 221 | const query = this.query(sql, [], (err, res) => { 222 | callback(err, res, query); 223 | }); 224 | }; 225 | 226 | // SELECT SQL statement generator by LIMIT 227 | // 228 | connection.selectLimit = function ( 229 | table, 230 | fields, 231 | limit, 232 | where, 233 | order, 234 | callback 235 | ) { 236 | where = this.where(where); 237 | if (typeof order === 'function') { 238 | callback = order; 239 | order = {}; 240 | } 241 | order = this.order(order); 242 | let sql = 'SELECT ' + fields + ' FROM ' + escapeIdentifier(table); 243 | if (where) sql = sql + ' WHERE ' + where; 244 | if (order) sql = sql + ' ORDER BY ' + order; 245 | sql = sql + ' LIMIT ' + limit.join(); 246 | const query = this.query(sql, [], (err, res) => { 247 | callback(err, res, query); 248 | }); 249 | }; 250 | 251 | // INSERT SQL statement generator 252 | // callback(err, id or false) 253 | // 254 | connection.insert = function (table, row, callback) { 255 | this.fields(table, (err, fields) => { 256 | if (err) { 257 | return callback( 258 | new Error('Error: Table "' + table + '" not found'), 259 | false 260 | ); 261 | } 262 | fields = Object.keys(fields); 263 | const rowKeys = Object.keys(row); 264 | const values = []; 265 | const columns = []; 266 | let i, field; 267 | for (i in fields) { 268 | field = fields[i]; 269 | if (rowKeys.includes(field)) { 270 | columns.push(field); 271 | values.push(this.escape(row[field])); 272 | } 273 | } 274 | const query = this.query( 275 | 'INSERT INTO ' + 276 | escapeIdentifier(table) + 277 | ' (' + 278 | columns.join(', ') + 279 | ') VALUES (' + 280 | values.join(', ') + 281 | ')', 282 | [], 283 | (err, res) => { 284 | callback(err, res ? res.insertId : false, query); 285 | } 286 | ); 287 | }); 288 | }; 289 | 290 | // UPDATE SQL statement generator 291 | // 292 | connection.update = function (table, row, where, callback) { 293 | if (typeof where === 'function') { 294 | callback = where; 295 | this.fields(table, (err, fields) => { 296 | if (err) { 297 | const error = new Error('Error: Table "' + table + '" not found'); 298 | return callback(error); 299 | } 300 | let where = ''; 301 | const data = []; 302 | const rowKeys = Object.keys(row); 303 | let i, field, fieldName; 304 | for (i in fields) { 305 | field = fields[i]; 306 | fieldName = field.Field; 307 | if (rowKeys.includes(fieldName)) { 308 | if (!where && (field.Key === 'PRI' || field.Key === 'UNI')) { 309 | where = fieldName + '=' + this.escape(row[fieldName]); 310 | } else { 311 | data.push(fieldName + '=' + this.escape(row[fieldName])); 312 | } 313 | } 314 | } 315 | if (where) { 316 | const query = this.query( 317 | 'UPDATE ' + 318 | escapeIdentifier(table) + 319 | ' SET ' + 320 | data.join(', ') + 321 | ' WHERE ' + 322 | where, 323 | [], 324 | (err, res) => { 325 | callback(err, res ? res.changedRows : false, query); 326 | } 327 | ); 328 | } else { 329 | const e = new Error( 330 | 'Error: can not insert into "' + 331 | table + 332 | '" because there is no primary or unique key specified' 333 | ); 334 | this.emit('error', e); 335 | callback(e, false); 336 | } 337 | }); 338 | } else { 339 | where = this.where(where); 340 | if (where) { 341 | const data = []; 342 | let i; 343 | for (i in row) data.push(i + '=' + this.escape(row[i])); 344 | const query = this.query( 345 | 'UPDATE ' + 346 | escapeIdentifier(table) + 347 | ' SET ' + 348 | data.join(', ') + 349 | ' WHERE ' + 350 | where, 351 | [], 352 | (err, res) => { 353 | callback(err, res ? res.changedRows : false, query); 354 | } 355 | ); 356 | } else { 357 | const e = new Error( 358 | 'Error: can update "' + 359 | table + 360 | '", because "where" parameter is empty' 361 | ); 362 | this.emit('error', e); 363 | callback(e, false); 364 | } 365 | } 366 | }; 367 | 368 | // INSERT OR UPDATE SQL statement generator 369 | // 370 | connection.upsert = function (table, row, callback) { 371 | this.fields(table, (err, fields) => { 372 | if (err) { 373 | const error = new Error('Error: Table "' + table + '" not found'); 374 | return callback(error); 375 | } 376 | const rowKeys = Object.keys(row); 377 | let uniqueKey = ''; 378 | let i, field, fieldName; 379 | for (i in fields) { 380 | field = fields[i]; 381 | fieldName = field.Field; 382 | if ( 383 | !uniqueKey && 384 | (field.Key === 'PRI' || field.Key === 'UNI') && 385 | rowKeys.includes(fieldName) 386 | ) { 387 | uniqueKey = fieldName; 388 | } 389 | } 390 | if (rowKeys.includes(uniqueKey)) { 391 | this.queryValue( 392 | 'SELECT count(*) FROM ' + 393 | escapeIdentifier(table) + 394 | ' WHERE ' + 395 | uniqueKey + 396 | '=' + 397 | this.escape(row[uniqueKey]), 398 | [], 399 | (err, count) => { 400 | if (count === 1) this.update(table, row, callback); 401 | else this.insert(table, row, callback); 402 | } 403 | ); 404 | } else { 405 | const e = new Error( 406 | 'Error: can not insert or update table "' + 407 | table + 408 | '", primary or unique key is not specified' 409 | ); 410 | this.emit('error', e); 411 | callback(e, false); 412 | } 413 | }); 414 | }; 415 | 416 | // DELETE SQL statement generator 417 | // callback(err, rowCount or false) 418 | // 419 | connection.delete = function (table, where, callback) { 420 | where = this.where(where); 421 | if (where) { 422 | const query = this.query( 423 | 'DELETE FROM ' + escapeIdentifier(table) + ' WHERE ' + where, 424 | [], 425 | (err, res) => { 426 | callback(err, res ? res.affectedRows : false, query); 427 | } 428 | ); 429 | } else { 430 | const e = new Error( 431 | 'Error: can not delete from "' + 432 | table + 433 | '", because "where" parameter is empty' 434 | ); 435 | this.emit('error', e); 436 | callback(e, false); 437 | } 438 | }; 439 | } 440 | }; 441 | 442 | const introspection = connection => { 443 | if (!connection._mixedIntrospection) { 444 | connection._mixedIntrospection = true; 445 | 446 | // Get primary key metadata 447 | // callback(err, row) 448 | // 449 | connection.primary = function (table, callback) { 450 | this.queryRow( 451 | 'SHOW KEYS FROM ' + 452 | escapeIdentifier(table) + 453 | ' WHERE Key_name = "PRIMARY"', 454 | [], 455 | (err, res) => { 456 | if (err) res = false; 457 | callback(err, res); 458 | } 459 | ); 460 | }; 461 | 462 | // Get foreign key metadata 463 | // callback(err, foreign) 464 | // 465 | connection.foreign = function (table, callback) { 466 | this.queryHash( 467 | 'SELECT CONSTRAINT_NAME, COLUMN_NAME, ORDINAL_POSITION, ' + 468 | 'POSITION_IN_UNIQUE_CONSTRAINT, REFERENCED_TABLE_NAME, ' + 469 | 'REFERENCED_COLUMN_NAME FROM information_schema.KEY_COLUMN_USAGE ' + 470 | 'WHERE REFERENCED_TABLE_NAME IS NOT NULL AND ' + 471 | 'CONSTRAINT_SCHEMA = DATABASE() AND TABLE_NAME = ? ' + 472 | 'ORDER BY REFERENCED_TABLE_NAME', 473 | [table], 474 | (err, res) => { 475 | if (err) res = false; 476 | callback(err, res); 477 | } 478 | ); 479 | }; 480 | 481 | // Get table constraints metadata 482 | // callback(err, constraints) 483 | // 484 | connection.constraints = function (table, callback) { 485 | this.queryHash( 486 | 'SELECT CONSTRAINT_NAME, UNIQUE_CONSTRAINT_NAME, ' + 487 | 'REFERENCED_TABLE_NAME, MATCH_OPTION, UPDATE_RULE, DELETE_RULE ' + 488 | 'FROM information_schema.REFERENTIAL_CONSTRAINTS ' + 489 | 'WHERE TABLE_NAME = ? ' + 490 | 'ORDER BY CONSTRAINT_NAME', 491 | [table], 492 | (err, res) => { 493 | if (err) res = false; 494 | callback(err, res); 495 | } 496 | ); 497 | }; 498 | 499 | // Get table fields metadata 500 | // callback(err, fields) 501 | // 502 | connection.fields = function (table, callback) { 503 | this.queryHash( 504 | 'SHOW FULL COLUMNS FROM ' + escapeIdentifier(table), 505 | [], 506 | (err, res) => { 507 | if (err) res = false; 508 | callback(err, res); 509 | } 510 | ); 511 | }; 512 | 513 | // Get connection databases array 514 | // callback(err, databases) 515 | // 516 | connection.databases = function (callback) { 517 | this.queryCol('SHOW DATABASES', [], (err, res) => { 518 | if (err) res = false; 519 | callback(err, res); 520 | }); 521 | }; 522 | 523 | // Get database tables list 524 | // callback(err, tables) 525 | // 526 | connection.databaseTables = function (database, callback) { 527 | this.queryHash( 528 | 'SELECT TABLE_NAME, TABLE_TYPE, ENGINE, VERSION, ROW_FORMAT, ' + 529 | 'TABLE_ROWS, AVG_ROW_LENGTH, DATA_LENGTH, MAX_DATA_LENGTH, ' + 530 | 'INDEX_LENGTH, DATA_FREE, AUTO_INCREMENT, CREATE_TIME, ' + 531 | 'UPDATE_TIME, CHECK_TIME, TABLE_COLLATION, CHECKSUM, ' + 532 | 'CREATE_OPTIONS, TABLE_COMMENT ' + 533 | 'FROM information_schema.TABLES WHERE TABLE_SCHEMA = ?', 534 | [database], 535 | (err, res) => { 536 | if (err) res = false; 537 | callback(err, res); 538 | } 539 | ); 540 | }; 541 | 542 | // Get current database table metadata 543 | // callback(err, tables) 544 | // 545 | connection.tables = function (callback) { 546 | this.queryHash( 547 | 'SELECT TABLE_NAME, TABLE_TYPE, ENGINE, VERSION, ROW_FORMAT, ' + 548 | 'TABLE_ROWS, AVG_ROW_LENGTH, DATA_LENGTH, MAX_DATA_LENGTH, ' + 549 | 'INDEX_LENGTH, DATA_FREE, AUTO_INCREMENT, CREATE_TIME, ' + 550 | 'UPDATE_TIME, CHECK_TIME, TABLE_COLLATION, CHECKSUM, ' + 551 | 'CREATE_OPTIONS, TABLE_COMMENT ' + 552 | 'FROM information_schema.TABLES WHERE TABLE_SCHEMA = DATABASE()', 553 | [], 554 | (err, res) => { 555 | if (err) res = false; 556 | callback(err, res); 557 | } 558 | ); 559 | }; 560 | 561 | // Get table metadata info 562 | // callback(err, metadata) 563 | // 564 | connection.tableInfo = function (table, callback) { 565 | this.queryRow('SHOW TABLE STATUS LIKE ?', [table], (err, res) => { 566 | if (err) res = false; 567 | callback(err, res); 568 | }); 569 | }; 570 | 571 | // Get table indexes metadata 572 | // callback(err, indexes) 573 | // 574 | connection.indexes = function (table, callback) { 575 | this.query( 576 | 'SHOW INDEX FROM ' + escapeIdentifier(table), 577 | [], 578 | (err, res) => { 579 | const result = {}; 580 | if (err) { 581 | callback(err, false); 582 | return; 583 | } 584 | let i, row; 585 | for (i in res) { 586 | row = res[i]; 587 | result[row.Key_name] = row; 588 | } 589 | callback(err, result); 590 | } 591 | ); 592 | }; 593 | 594 | // Get server process list 595 | // callback(err, processes) 596 | // 597 | connection.processes = function (callback) { 598 | this.query( 599 | 'SELECT * FROM information_schema.PROCESSLIST', 600 | [], 601 | (err, res) => { 602 | if (err) res = false; 603 | callback(err, res); 604 | } 605 | ); 606 | }; 607 | 608 | // Get server global variables 609 | // callback(err, variables) 610 | // 611 | connection.globalVariables = function (callback) { 612 | this.queryKeyValue( 613 | 'SELECT * FROM information_schema.GLOBAL_VARIABLES', 614 | [], 615 | (err, res) => { 616 | if (err) res = false; 617 | callback(err, res); 618 | } 619 | ); 620 | }; 621 | 622 | // Get server global status 623 | // callback(err, status) 624 | // 625 | connection.globalStatus = function (callback) { 626 | this.queryKeyValue( 627 | 'SELECT * FROM information_schema.GLOBAL_STATUS', 628 | [], 629 | (err, res) => { 630 | if (err) res = false; 631 | callback(err, res); 632 | } 633 | ); 634 | }; 635 | 636 | // Get database users 637 | // callback(err, users) 638 | // 639 | connection.users = function (callback) { 640 | this.query('SELECT * FROM mysql.user', [], (err, res) => { 641 | if (err) res = false; 642 | callback(err, res); 643 | }); 644 | }; 645 | } 646 | }; 647 | 648 | module.exports = { 649 | upgrade, 650 | introspection, 651 | }; 652 | --------------------------------------------------------------------------------