UNPKG

sharp-db

Version:

Classes for running SQL and building select queries for MySQL in Node

399 lines (365 loc) 34.8 kB
<!DOCTYPE html> <html lang="en"> <head> <meta charset="utf-8"> <meta name="viewport" content="width=device-width,initial-scale=1"> <title>SqlBuilder/SqlBuilder.js - Documentation</title> <script src="scripts/prettify/prettify.js"></script> <script src="scripts/prettify/lang-css.js"></script> <!--[if lt IE 9]> <script src="//html5shiv.googlecode.com/svn/trunk/html5.js"></script> <![endif]--> <link type="text/css" rel="stylesheet" href="https://code.ionicframework.com/ionicons/2.0.1/css/ionicons.min.css"> <link type="text/css" rel="stylesheet" href="styles/prettify-tomorrow.css"> <link type="text/css" rel="stylesheet" href="styles/jsdoc-default.css"> </head> <body> <input type="checkbox" id="nav-trigger" class="nav-trigger" /> <label for="nav-trigger" class="navicon-button x"> <div class="navicon"></div> </label> <label for="nav-trigger" class="overlay"></label> <nav> <li class="nav-link nav-home-link"><a href="index.html">Home</a></li><li class="nav-heading">Classes</li><li class="nav-heading"><span class="nav-item-type type-class">C</span><span class="nav-item-name"><a href="DataBroker.html">DataBroker</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="DataBroker.html#cleanup">cleanup</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="DataBroker.html#created_and_modified">created_and_modified</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="DataBroker.html#createdAndModified">createdAndModified</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="DataBroker.html#delete">delete</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="DataBroker.html#insert">insert</a></span></li><li class="nav-heading"><span class="nav-item-type type-class">C</span><span class="nav-item-name"><a href="Db.html">Db</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Db.html#.destroyAll">destroyAll</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Db.html#.endAll">endAll</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Db.html#.factory">factory</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Db.html#.withInstance">withInstance</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Db.html#beginTransaction">beginTransaction</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Db.html#bindArgs">bindArgs</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Db.html#commit">commit</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Db.html#connect">connect</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Db.html#connectOnce">connectOnce</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Db.html#delete">delete</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Db.html#deleteFrom">deleteFrom</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Db.html#destroy">destroy</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Db.html#emit">emit</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Db.html#emitError">emitError</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Db.html#end">end</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Db.html#escape">escape</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Db.html#escapeLike">escapeLike</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Db.html#escapeQuoteless">escapeQuoteless</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Db.html#exportAsSql">exportAsSql</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Db.html#insert">insert</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Db.html#insertExtended">insertExtended</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Db.html#insertInto">insertInto</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Db.html#insertIntoOnDuplicateKeyUpdate">insertIntoOnDuplicateKeyUpdate</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Db.html#multiQuery">multiQuery</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Db.html#query">query</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Db.html#quote">quote</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Db.html#rollback">rollback</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Db.html#select">select</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Db.html#selectByKey">selectByKey</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Db.html#selectExists">selectExists</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Db.html#selectFirst">selectFirst</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Db.html#selectFrom">selectFrom</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Db.html#selectGrouped">selectGrouped</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Db.html#selectHash">selectHash</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Db.html#selectId">selectId</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Db.html#selectIndexed">selectIndexed</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Db.html#selectList">selectList</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Db.html#selectOrCreate">selectOrCreate</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Db.html#selectOrCreateId">selectOrCreateId</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Db.html#selectUuid">selectUuid</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Db.html#selectValue">selectValue</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Db.html#startTransaction">startTransaction</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Db.html#tpl">tpl</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Db.html#update">update</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Db.html#updateTable">updateTable</a></span></li><li class="nav-heading"><span class="nav-item-type type-class">C</span><span class="nav-item-name"><a href="DbEvent.html">DbEvent</a></span></li><li class="nav-heading"><span class="nav-item-type type-class">C</span><span class="nav-item-name"><a href="Parser.html">Parser</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Parser.html#_extractSubqueries">_extractSubqueries</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Parser.html#_handleConditions">_handleConditions</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Parser.html#_handleCrossJoin">_handleCrossJoin</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Parser.html#_handleFrom">_handleFrom</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Parser.html#_handleFullJoin">_handleFullJoin</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Parser.html#_handleFullOuterJoin">_handleFullOuterJoin</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Parser.html#_handleGroupBy">_handleGroupBy</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Parser.html#_handleHaving">_handleHaving</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Parser.html#_handleInnerJoin">_handleInnerJoin</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Parser.html#_handleLeftJoin">_handleLeftJoin</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Parser.html#_handleLeftOuterJoin">_handleLeftOuterJoin</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Parser.html#_handleLimit">_handleLimit</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Parser.html#_handleOffset">_handleOffset</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Parser.html#_handleOrderBy">_handleOrderBy</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Parser.html#_handleRightJoin">_handleRightJoin</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Parser.html#_handleRightOuterJoin">_handleRightOuterJoin</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Parser.html#_handleSelect">_handleSelect</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Parser.html#_handleWhere">_handleWhere</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Parser.html#_injectSubqueries">_injectSubqueries</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Parser.html#_split">_split</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Parser.html#_stripComments">_stripComments</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Parser.html#parse">parse</a></span></li><li class="nav-heading"><span class="nav-item-type type-class">C</span><span class="nav-item-name"><a href="Select.html">Select</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Select.html#._extractBindingName">_extractBindingName</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Select.html#.init">init</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Select.html#.parse">parse</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Select.html#_conditions">_conditions</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Select.html#_isEntirelyDigits">_isEntirelyDigits</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Select.html#_isEntirelyDigitsNoZeros">_isEntirelyDigitsNoZeros</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Select.html#_isPlaceholder">_isPlaceholder</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Select.html#_spliceChildData">_spliceChildData</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Select.html#_spliceSiblingData">_spliceSiblingData</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Select.html#bind">bind</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Select.html#column">column</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Select.html#columns">columns</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Select.html#crossJoin">crossJoin</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Select.html#escape">escape</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Select.html#escapeLike">escapeLike</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Select.html#escapeQuoteless">escapeQuoteless</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Select.html#fetch">fetch</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Select.html#fetchFirst">fetchFirst</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Select.html#fetchGrouped">fetchGrouped</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Select.html#fetchHash">fetchHash</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Select.html#fetchIndexed">fetchIndexed</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Select.html#fetchList">fetchList</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Select.html#fetchValue">fetchValue</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Select.html#foundRows">foundRows</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Select.html#from">from</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Select.html#fullJoin">fullJoin</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Select.html#fullOuterJoin">fullOuterJoin</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Select.html#getClone">getClone</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Select.html#getFoundRowsQuery">getFoundRowsQuery</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Select.html#getFoundRowsSql">getFoundRowsSql</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Select.html#groupBy">groupBy</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Select.html#having">having</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Select.html#innerJoin">innerJoin</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Select.html#join">join</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Select.html#leftJoin">leftJoin</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Select.html#leftOuterJoin">leftOuterJoin</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Select.html#limit">limit</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Select.html#normalized">normalized</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Select.html#offset">offset</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Select.html#option">option</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Select.html#orderBy">orderBy</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Select.html#orHaving">orHaving</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Select.html#orWhere">orWhere</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Select.html#page">page</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Select.html#parse">parse</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Select.html#reset">reset</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Select.html#rightJoin">rightJoin</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Select.html#rightOuterJoin">rightOuterJoin</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Select.html#sortField">sortField</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Select.html#table">table</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Select.html#tables">tables</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Select.html#toBoundSql">toBoundSql</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Select.html#toString">toString</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Select.html#unbind">unbind</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Select.html#unjoin">unjoin</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Select.html#where">where</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Select.html#whereBetween">whereBetween</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Select.html#withChildData">withChildData</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Select.html#withSiblingData">withSiblingData</a></span></li><li class="nav-heading"><span class="nav-item-type type-class">C</span><span class="nav-item-name"><a href="Ssh.html">Ssh</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Ssh.html#end">end</a></span></li><li class="nav-item"><span class="nav-item-type type-function">F</span><span class="nav-item-name"><a href="Ssh.html#tunnelTo">tunnelTo</a></span></li> </nav> <div id="main"> <h1 class="page-title">SqlBuilder/SqlBuilder.js</h1> <section> <article> <pre class="prettyprint source linenums"><code>const mysql = require('mysql2'); const chunk = require('../chunk/chunk.js'); const forOwn = require('../forOwnDefined/forOwnDefined.js'); class SqlBuilder { /** * Escape an identifier such as a table or column * @param identifier * @return {*} */ static quote(identifier) { if (/[`()]/.test(identifier)) { return identifier; } let quoted = mysql.escapeId(identifier); if (/`\*`$/.test(quoted)) { quoted = quoted.slice(0, -3) + '*'; } return quoted; } /** * Escape a value for use in a raw query and surround with apostrophes * @param {*} value The value to escape * @return {String} */ static escape(value) { return mysql.escape(value); } /** * Build a basic SELECT statement * @param {String} table The name of the table * @param {Array} fields An array of field names to select * @param {Object} criteria Params to construct the WHERE clause - see SqlBuilder#buildWheres * @param {String} extra Additional raw SQL such as GROUP BY, ORDER BY, or LIMIT * @return {String} * @see SqlBuilder#buildWheres * @see Db#selectFrom * @see Select */ static selectFrom(table, fields = [], criteria = {}, extra = '') { if (!Array.isArray(fields)) { throw new Error('SqlBuilder.selectFrom fields must be an array'); } if (typeof criteria !== 'object') { throw new Error('SqlBuilder.selectFrom criteria must be an array'); } const escFields = fields.map(field => SqlBuilder.quote(field)); const escFieldsString = fields.length ? escFields.join(', ') : '*'; const escTable = SqlBuilder.quote(table); const escWhere = SqlBuilder.buildWheres(criteria); const sql = `SELECT ${escFieldsString} FROM ${escTable} WHERE ${escWhere} ${extra}`; return sql.trim(); } /** * Select the record with the given column value * @param {String} table The name of the table from which to select * @param {String} column The name of the column from which to select * @param {String} value The value of the record for that column * @return {String} */ static selectBy(table, column, value) { const escTable = this.quote(table); const escColumn = this.quote(column); const escValue = this.escape(value); return `SELECT * FROM ${escTable} WHERE ${escColumn} = ${escValue}`; } /** * Build an INSERT statement * @param {String} table The name of the table * @param {Object} row column-value pairs to insert * @return {String} */ static insertInto(table, row) { const sets = []; forOwn(row, (value, field) => { sets.push(SqlBuilder.quote(field) + '=' + SqlBuilder.escape(value)); }); if (sets.length === 0) { throw new Error( 'SqlBuilder.insertInto requires a non-empty insert Object' ); } const escTable = SqlBuilder.quote(table); const setSql = sets.join(', '); return `INSERT INTO ${escTable} SET ${setSql}`; } /** * Build an "INSERT INTO ... ON DUPLICATE KEY UPDATE" query * @param {String} table The name of the table * @param {Object} insert An array with column => value pairs for insertion * @param {Object} update An array with column => value pairs for update * @return {String} */ static insertIntoOnDuplicateKeyUpdate(table, insert, update) { const sets = []; forOwn(insert, (value, field) => { sets.push(SqlBuilder.quote(field) + '=' + SqlBuilder.escape(value)); }); if (sets.length === 0) { throw new Error( 'SqlBuilder.insertIntoOnDuplicateKeyUpdate requires a non-empty insert Object' ); } // build update expression const updates = []; forOwn(update, (value, field) => { updates.push(SqlBuilder.quote(field) + '=' + SqlBuilder.escape(value)); }); if (updates.length === 0) { throw new Error( 'Db.insertIntoOnDuplicateKeyUpdate requires a non-empty update Object' ); } table = SqlBuilder.quote(table); const setSql = sets.join(', '); const updateSql = updates.join(', '); // combine return `INSERT INTO ${table} SET ${setSql} ON DUPLICATE KEY UPDATE ${updateSql}`; } /** * Build an INSERT statement with multiple rows * @param {String} table The name of the table * @param {Array} rows An Array of objects, each with column-value pairs to insert * @return {String} */ static insertExtended(table, rows) { // build insert expression if (!Array.isArray(rows) || rows.length === 0) { throw new Error('Db.insertExtended rows must be a non-empty array'); } const fields = []; forOwn(rows[0], (value, field) => { fields.push(SqlBuilder.quote(field)); }); const batches = []; rows.forEach(insert => { const values = []; forOwn(insert, value => { values.push(SqlBuilder.escape(value)); }); batches.push('(' + values.join(', ') + ')'); }); const escTable = SqlBuilder.quote(table); const fieldsSql = fields.join(', '); const batchesSql = batches.join(', '); return `INSERT INTO ${escTable} (${fieldsSql}) VALUES ${batchesSql}`; } /** * Build an UPDATE statement * @param {String} table The name of the table * @param {Object} set An array of column-value pairs to update * @param {Object} where Params to construct the WHERE clause - see SqlBuilder#buildWheres * @return {String} * @see SqlBuilder#buildWheres */ static updateTable(table, set, where = {}) { const sets = []; forOwn(set, (value, field) => { sets.push(SqlBuilder.quote(field) + '=' + SqlBuilder.escape(value)); }); if (sets.length === 0) { throw new Error('Db.updateTable requires a non-empty set Object'); } const escTable = SqlBuilder.quote(table); const setSql = sets.join(', '); const escWhere = SqlBuilder.buildWheres(where); return `UPDATE ${escTable} SET ${setSql} WHERE ${escWhere}`; } /** * Construct a DELETE query * @param {String} table The name of the table from which to delete * @param {Object} where WHERE conditions on which to delete - see SqlBuilder#buildWheres * @param {Number} limit Limit deletion to this many records * @return {String} * @see SqlBuilder#buildWheres */ static deleteFrom(table, where, limit) { const escTable = SqlBuilder.quote(table); const escWhere = SqlBuilder.buildWheres(where); let sql = `DELETE FROM ${escTable} WHERE ${escWhere}`; if (limit > 0) { sql += ` LIMIT ${Number(limit)}`; } return sql; } /** * Construct INSERT statements suitable for a backup * @param {String} table The name of the table from which to fetch records * @param {Object} rows Rows to export * @param {Object} options Additional options * @property {Object[]} [fields=null] List of objects with "name" property for column names * @property {Number} [chunkSize=250] If > 0, restrict INSERT STATEMENTS to a maximum of this many records * @property {Boolean} [discardIds=false] If true, columns selected as "id" will have a NULL value * @property {Boolean} [disableForeignKeyChecks=false] If true, add statements to disable and re-enable foreign key checks * @property {Boolean} [lockTables=false] If true, add statements to lock and unlock tables * @return {String} */ static exportRows( table, rows, { fields = null, chunkSize = 250, discardIds = false, truncateTable = false, disableForeignKeyChecks = false, lockTables = false, } = {} ) { if (rows.length === 0) { return null; } // read field names or infer from rows const fieldNames = fields ? fields.map(f => f.name) : Object.keys(rows[0]); const quotedFields = fieldNames.map(SqlBuilder.quote); const fieldsString = quotedFields.join(','); const quotedTable = SqlBuilder.quote(table); // start building lines of sql to insert const lines = []; if (disableForeignKeyChecks) { lines.push( '/*!40014 SET @OLD_FOREIGN_KEY_CHECKS=@@FOREIGN_KEY_CHECKS, FOREIGN_KEY_CHECKS=0 */;' ); } if (lockTables) { lines.push(`LOCK TABLES ${quotedTable} WRITE;`); } if (truncateTable) { lines.push(`TRUNCATE TABLE ${quotedTable};`); } // take rows in chunks so a single statement isn't too long const chunks = chunk(rows, chunkSize); for (const chunkOfRows of chunks) { const rowStrings = []; for (const values of chunkOfRows) { const escapedValues = []; // collect the value for each field for (const field of fields) { if (discardIds &amp;&amp; field.name === 'id') { escapedValues.push('NULL'); } else { escapedValues.push(SqlBuilder.escape(values[field.name])); } } const valuesString = escapedValues.join(','); rowStrings.push(`(${valuesString})`); } const insertsString = rowStrings.join(',\n'); lines.push( `INSERT INTO ${quotedTable} (${fieldsString}) VALUES\n${insertsString};` ); } if (lockTables) { lines.push('UNLOCK TABLES;'); } if (disableForeignKeyChecks) { lines.push('/*!40014 SET FOREIGN_KEY_CHECKS=@OLD_FOREIGN_KEY_CHECKS */;'); } return lines.join('\n'); } /** * Construct where clause element from the given field and value * @param {String} field The field or field space operator * @param {*} value The value to bind * @return {String} * @example * db.buildWhere('start_date BETWEEN', ['2012-01-01','2013-01-01']); * db.buildWhere('start_date >', '2013-01-01'); * db.buildWhere('start_date !=', '2013-01-01'); * db.buildWhere('start_date', null); // `start_date` IS NULL * db.buildWhere('start_date !=', null); // `start_date` IS NOT NULL * db.buildWhere('id', [1,2,3]); // `id` IN (1,2,3) * db.buildWhere('id !=', [1,2,3]); // `id` NOT IN (1,2,3) * db.buildWhere('id IN', [1,2,3]); // `id` IN (1,2,3) * db.buildWhere('id NOT IN', [1,2,3]); // `id` NOT IN (1,2,3) */ static buildWhere(field, value = undefined) { if (value === undefined) { return field; } let [name, operator] = field.split(/\s+/); name = SqlBuilder.quote(name); operator = operator ? operator.toUpperCase() : '='; if (operator === 'BETWEEN') { const val0 = SqlBuilder.escape(value[0]); const val1 = SqlBuilder.escape(value[1]); return `${name} BETWEEN ${val0} AND ${val1}`; } else if (value === null) { return operator === '=' ? `${name} IS NULL` : `${name} IS NOT NULL`; } else if (Array.isArray(value)) { const values = value.map(val => SqlBuilder.escape(val)); return operator === '=' || operator === 'IN' ? `${name} IN(${values})` : `${name} NOT IN(${values})`; } const escVal = SqlBuilder.escape(value); return `${name} ${operator} ${escVal}`; } /** * Build a where clause from an object of field-value pairs. * Used internally by #selectFrom, #updateTable, #deleteFrom * @see Db#buildWhere * @param {Object} wheres An object with field-value pairs (field may be field space operator) * @return {String} * @example * SqlBuilder.buildWheres({ * 'start_date BETWEEN: ['2012-01-01','2013-01-01'], * 'start_date >': '2013-01-01', * 'start_date !=': '2013-01-01', * 'start_date': null, // `start_date` IS NULL * 'start_date !=': null, // `start_date` IS NOT NULL * id: [1,2,3], // `id` IN (1,2,3) * 'id !=': [1,2,3], // `id` NOT IN (1,2,3) * 'id IN': [1,2,3], // `id` IN (1,2,3) * 'id NOT IN': [1,2,3], // `id` NOT IN (1,2,3) * }) */ static buildWheres(wheres) { const clauses = []; forOwn(wheres, (value, field) => { clauses.push(SqlBuilder.buildWhere(field, value)); }); return clauses.length ? clauses.join(' AND ') : '1'; } } module.exports = SqlBuilder; </code></pre> </article> </section> </div> <br class="clear"> <footer> Generated by <a href="https://github.com/jsdoc3/jsdoc">JSDoc 3.6.11</a> on Mon Sep 05 2022 18:14:46 GMT-0600 (Mountain Daylight Time) using the Minami theme. </footer> <script>prettyPrint();</script> <script src="scripts/linenumber.js"></script> </body> </html>