npm install [email protected]
Despite the alpha tag, this is the recommended version for new applications. For information about the previous 0.9.x releases, visit the v0.9 branch.
Sometimes I may also ask you to install the latest version from Github to check if a bugfix is working. In this case, please do:
npm install felixge/node-mysql
This is a node.js driver for mysql. It is written in JavaScript, does not require compiling, and is 100% MIT licensed.
Here is an example on how to use it:
var mysql = require('mysql');
var connection = mysql.createConnection({
host : 'localhost',
user : 'me',
password : 'secret',
});
connection.connect();
connection.query('SELECT 1 + 1 AS solution', function(err, rows, fields) {
if (err) throw err;
console.log('The solution is: ', rows[0].solution);
});
connection.end();
From this example, you can learn the following:
- Every method you invoke on a connection is queued and executed in sequence.
- Closing the connection is done using
end()
which makes sure all remaining queries are executed before sending a quit packet to the mysql server.
Thanks goes to the people who have contributed code to this module, see the GitHub Contributors page.
Additionally I'd like to thank the following people:
- Andrey Hristov (Oracle) - for helping me with protocol questions.
- Ulf Wendel (Oracle) - for helping me with protocol questions.
The following companies have supported this project financially, allowing me to spend more time on it (ordered by time of contribution):
- Transloadit (my startup, we do file uploading & video encoding as a service, check it out)
- Joyent
- pinkbike.com
- Holiday Extras (they are hiring)
- Newscope (they are hiring)
If you are interested in sponsoring a day or more of my time, please get in touch.
If you'd like to discuss this module, or ask questions about it, please use one of the following:
- Mailing list: https://groups.google.com/forum/#!forum/node-mysql
- IRC Channel: #node.js (on freenode.net, I pay attention to any message
including the term
mysql
)
The recommended way to establish a connection is this:
var mysql = require('mysql');
var connection = mysql.createConnection({
host : 'example.org',
user : 'bob',
password : 'secret',
});
connection.connect(function(err) {
// connected! (unless `err` is set)
});
However, a connection can also be implicitly established by invoking a query:
var mysql = require('mysql');
var connection = mysql.createConnection(...);
connection.query('SELECT 1', function(err, rows) {
// connected! (unless `err` is set)
});
Depending on how you like to handle your errors, either method may be appropriate. Any type of connection error (handshake or network) is considered a fatal error, see the Error Handling section for more information.
When establishing a connection, you can set the following options:
host
: The hostname of the database you are connecting to. (Default:localhost
)port
: The port number to connect to. (Default:3306
)socketPath
: The path to a unix domain socket to connect to. When usedhost
andport
are ignored.user
: The MySQL user to authenticate as.password
: The password of that MySQL user.database
: Name of the database to use for this connection (Optional).charset
: The charset for the connection. (Default:'UTF8_GENERAL_CI'
. Value needs to be all in upper case letters!)timezone
: The timezone used to store local dates. (Default:'local'
)stringifyObjects
: Stringify objects instead of converting to values. See issue #501. (Default:'false'
)insecureAuth
: Allow connecting to MySQL instances that ask for the old (insecure) authentication method. (Default:false
)typeCast
: Determines if column values should be converted to native JavaScript types. (Default:true
)queryFormat
: A custom query format function. See Custom format.supportBigNumbers
: When dealing with big numbers (BIGINT and DECIMAL columns) in the database, you should enable this option (Default:false
).bigNumberStrings
: Enabling bothsupportBigNumbers
andbigNumberStrings
forces big numbers (BIGINT and DECIMAL columns) to be always returned as JavaScript String objects (Default:false
). EnablingsupportBigNumbers
but leavingbigNumberStrings
disabled will return big numbers as String objects only when they cannot be accurately represented with [JavaScript Number objects] (http://ecma262-5.com/ELS5_HTML.htm#Section_8.5) (which happens when they exceed the [-2^53, +2^53] range), otherwise they will be returned as Number objects. This option is ignored ifsupportBigNumbers
is disabled.debug
: Prints protocol details to stdout. (Default:false
)multipleStatements
: Allow multiple mysql statements per query. Be careful with this, it exposes you to SQL injection attacks. (Default:false
)flags
: List of connection flags to use other than the default ones. It is also possible to blacklist default ones. For more information, check Connection Flags.
In addition to passing these options as an object, you can also use a url string. For example:
var connection = mysql.createConnection('mysql://user:pass@host/db?debug=true&charset=BIG5_CHINESE_CI&timezone=-0700');
Note: The query values are first attempted to be parsed as JSON, and if that fails assumed to be plaintext strings.
There are two ways to end a connection. Terminating a connection gracefully is
done by calling the end()
method:
connection.end(function(err) {
// The connection is terminated now
});
This will make sure all previously enqueued queries are still before sending a
COM_QUIT
packet to the MySQL server. If a fatal error occurs before the
COM_QUIT
packet can be sent, an err
argument will be provided to the
callback, but the connection will be terminated regardless of that.
An alternative way to end the connection is to call the destroy()
method.
This will cause an immediate termination of the underlying socket.
Additionally destroy()
guarantees that no more events or callbacks will be
triggered for the connection.
connection.destroy();
Unlike end()
the destroy()
method does not take a callback argument.
Connections can be pooled to ease sharing a single connection, or managing multiple connections.
var mysql = require('mysql');
var pool = mysql.createPool({
host : 'example.org',
user : 'bob',
password : 'secret',
});
pool.getConnection(function(err, connection) {
// connected! (unless `err` is set)
});
If you need to set session variables on the connection before it gets used,
you can listen to the connection
event.
pool.on('connection', function(err, connection) {
connection.query('SET SESSION auto_increment_increment=1')
});
When you are done with a connection, just call connection.end()
and the
connection will return to the pool, ready to be used again by someone else.
var mysql = require('mysql');
var pool = mysql.createPool(...);
pool.getConnection(function(err, connection) {
// Use the connection
connection.query( 'SELECT something FROM sometable', function(err, rows) {
// And done with the connection.
connection.end();
// Don't use the connection here, it has been returned to the pool.
});
});
If you would like to close the connection and remove it from the pool, use
connection.destroy()
instead. The pool will create a new connection the next
time one is needed.
Connections are lazily created by the pool. If you configure the pool to allow up to 100 connections, but only ever use 5 simultaneously, only 5 connections will be made. Connections are also cycled round-robin style, with connections being taken from the top of the pool and returning to the bottom.
Pools accept all the same options as a connection. When creating a new connection, the options are simply passed to the connection constructor. In addition to those options pools accept a few extras:
createConnection
: The function to use to create the connection. (Default:mysql.createConnection
)waitForConnections
: Determines the pool's action when no connections are available and the limit has been reached. Iftrue
, the pool will queue the connection request and call it when one becomes available. Iffalse
, the pool will immediately call back with an error. (Default:true
)connectionLimit
: The maximum number of connections to create at once. (Default:10
)queueLimit
: The maximum number of connection requests the pool will queue before returning an error fromgetConnection
. If set to0
, there is no limit to the number of queued connection requests. (Default:0
)
PoolCluster provides multiple hosts connection. (group & retry & selector)
// create
var poolCluster = mysql.createPoolCluster();
poolCluster.add(config); // anonymous group
poolCluster.add('MASTER', masterConfig);
poolCluster.add('SLAVE1', slave1Config);
poolCluster.add('SLAVE2', slave2Config);
// Target Group : ALL(anonymous, MASTER, SLAVE1-2), Selector : round-robin(default)
poolCluster.getConnection(function (err, connection) {});
// Target Group : MASTER, Selector : round-robin
poolCluster.getConnection('MASTER', function (err, connection) {});
// Target Group : SLAVE1-2, Selector : order
// If can't connect to SLAVE1, return SLAVE2. (remove SLAVE1 in the cluster)
poolCluster.on('remove', function (nodeId) {
console.log('REMOVED NODE : ' + nodeId); // nodeId = SLAVE1
});
poolCluster.getConnection('SLAVE*', 'ORDER', function (err, connection) {});
// of namespace : of(pattern, selector)
poolCluster.of('*').getConnection(function (err, connection) {});
var pool = poolCluster.of('SLAVE*', 'RANDOM');
pool.getConnection(function (err, connection) {});
pool.getConnection(function (err, connection) {});
// destroy
poolCluster.end();
canRetry
: Iftrue
,PoolCluster
will attempt to reconnect when connection fails. (Default:true
)removeNodeErrorCount
: If connection fails, node'serrorCount
increases. WhenerrorCount
is greater thanremoveNodeErrorCount
, remove a node in thePoolCluster
. (Default:5
)defaultSelector
: The default selector. (Default:RR
)RR
: Select one alternately. (Round-Robin)RANDOM
: Select the node by random function.ORDER
: Select the first node available unconditionally.
var clusterConfig = {
removeNodeErrorCount: 1, // Remove the node immediately when connection fails.
defaultSelector: 'ORDER',
};
var poolCluster = mysql.createPoolCluster(clusterConfig);
MySQL offers a changeUser command that allows you to alter the current user and other aspects of the connection without shutting down the underlying socket:
connection.changeUser({user : 'john'}, function(err) {
if (err) throw err;
});
The available options for this feature are:
user
: The name of the new user (defaults to the previous one).password
: The password of the new user (defaults to the previous one).charset
: The new charset (defaults to the previous one).database
: The new database (defaults to the previous one).
A sometimes useful side effect of this functionality is that this function also resets any connection state (variables, transactions, etc.).
Errors encountered during this operation are treated as fatal connection errors by this module.
You may lose the connection to a MySQL server due to network problems, the
server timing you out, or the server crashing. All of these events are
considered fatal errors, and will have the err.code = 'PROTOCOL_CONNECTION_LOST'
. See the Error Handling section
for more information.
The best way to handle such unexpected disconnects is shown below:
function handleDisconnect(connection) {
connection.on('error', function(err) {
if (!err.fatal) {
return;
}
if (err.code !== 'PROTOCOL_CONNECTION_LOST') {
throw err;
}
console.log('Re-connecting lost connection: ' + err.stack);
connection = mysql.createConnection(connection.config);
handleDisconnect(connection);
connection.connect();
});
}
handleDisconnect(connection);
As you can see in the example above, re-connecting a connection is done by establishing a new connection. Once terminated, an existing connection object cannot be re-connected by design.
With Pool, disconnected connections will be removed from the pool freeing up space for a new connection to be created on the next getConnection call.
In order to avoid SQL Injection attacks, you should always escape any user
provided data before using it inside a SQL query. You can do so using the
connection.escape()
method:
var userId = 'some user provided value';
var sql = 'SELECT * FROM users WHERE id = ' + connection.escape(userId);
connection.query(sql, function(err, results) {
// ...
});
Alternatively, you can use ?
characters as placeholders for values you would
like to have escaped like this:
connection.query('SELECT * FROM users WHERE id = ?', [userId], function(err, results) {
// ...
});
This looks similar to prepared statements in MySQL, however it really just uses
the same connection.escape()
method internally.
Different value types are escaped differently, here is how:
- Numbers are left untouched
- Booleans are converted to
true
/false
strings - Date objects are converted to
'YYYY-mm-dd HH:ii:ss'
strings - Buffers are converted to hex strings, e.g.
X'0fa5'
- Strings are safely escaped
- Arrays are turned into list, e.g.
['a', 'b']
turns into'a', 'b'
- Nested arrays are turned into grouped lists (for bulk inserts), e.g.
[['a', 'b'], ['c', 'd']]
turns into('a', 'b'), ('c', 'd')
- Objects are turned into
key = 'val'
pairs. Nested objects are cast to strings. undefined
/null
are converted toNULL
NaN
/Infinity
are left as-is. MySQL does not support these, and trying to insert them as values will trigger MySQL errors until they implement support.
If you paid attention, you may have noticed that this escaping allows you to do neat things like this:
var post = {id: 1, title: 'Hello MySQL'};
var query = connection.query('INSERT INTO posts SET ?', post, function(err, result) {
// Neat!
});
console.log(query.sql); // INSERT INTO posts SET `id` = 1, `title` = 'Hello MySQL'
If you feel the need to escape queries by yourself, you can also use the escaping function directly:
var query = "SELECT * FROM posts WHERE title=" + mysql.escape("Hello MySQL");
console.log(query); // SELECT * FROM posts WHERE title='Hello MySQL'
If you can't trust an SQL identifier (database / table / column name) because it is
provided by a user, you should escape it with mysql.escapeId(identifier)
like this:
var sorter = 'date';
var query = 'SELECT * FROM posts ORDER BY ' + mysql.escapeId(sorter);
console.log(query); // SELECT * FROM posts ORDER BY `date`
It also supports adding qualified identifiers. It will escape both parts.
var sorter = 'date';
var query = 'SELECT * FROM posts ORDER BY ' + mysql.escapeId('posts.' + sorter);
console.log(query); // SELECT * FROM posts ORDER BY `posts`.`date`
Alternatively, you can use ??
characters as placeholders for identifiers you would
like to have escaped like this:
connection.query('SELECT * FROM ?? WHERE id = ?', ['users', userId], function(err, results) {
// ...
});
Please note that this last character sequence is experimental and syntax might change
When you pass an Object to .escape()
or .query()
, .escapeId()
is used to avoid SQL injection in object keys.
If you prefer to have another type of query escape format, there's a connection configuration option you can use to define a custom format function. You can access the connection object if you want to use the built-in .escape()
or any other connection function.
Here's an example of how to implement another format:
connection.config.queryFormat = function (query, values) {
if (!values) return query;
return query.replace(/\:(\w+)/g, function (txt, key) {
if (values.hasOwnProperty(key)) {
return this.escape(values[key]);
}
return txt;
}.bind(this));
};
connection.query("UPDATE posts SET title = :title", { title: "Hello MySQL" });
If you are inserting a row into a table with an auto increment primary key, you can retrieve the insert id like this:
connection.query('INSERT INTO posts SET ?', {title: 'test'}, function(err, result) {
if (err) throw err;
console.log(result.insertId);
});
When dealing with big numbers (above JavaScript Number precision limit), you should
consider enabling supportBigNumbers
option to be able to read the insert id as a
string, otherwise it will throw.
This option is also required when fetching big numbers from the database, otherwise you will get values rounded to hundreds or thousands due to the precision limit.
The MySQL protocol is sequential, this means that you need multiple connections to execute queries in parallel. You can use a Pool to manage connections, one simple approach is to create one connection per incoming http request.
Sometimes you may want to select large quantities of rows and process each of them as they are received. This can be done like this:
var query = connection.query('SELECT * FROM posts');
query
.on('error', function(err) {
// Handle error, an 'end' event will be emitted after this as well
})
.on('fields', function(fields) {
// the field packets for the rows to follow
})
.on('result', function(row) {
// Pausing the connnection is useful if your processing involves I/O
connection.pause();
processRow(row, function() {
connection.resume();
});
})
.on('end', function() {
// all rows have been received
});
Please note a few things about the example above:
- Usually you will want to receive a certain amount of rows before starting to
throttle the connection using
pause()
. This number will depend on the amount and size of your rows. pause()
/resume()
operate on the underlying socket and parser. You are guaranteed that no more'result'
events will fire after callingpause()
.- You MUST NOT provide a callback to the
query()
method when streaming rows. - The
'result'
event will fire for both rows as well as OK packets confirming the success of a INSERT/UPDATE query.
Additionally you may be interested to know that it is currently not possible to stream individual row columns, they will always be buffered up entirely. If you have a good use case for streaming large fields to and from MySQL, I'd love to get your thoughts and contributions on this.
Piping results with Streams2 (Node v0.10+)
The query object provides a convenience method .stream([options])
that wraps
query events into a Readable
Streams2 object. This stream can easily be piped downstream and provides
automatic pause/resume, based on downstream congestion and the optional
highWaterMark
. The objectMode
parameter of the stream is set to true
by
default.
For example, piping query results into another stream (with a max buffer of 5 objects) is simply:
connection.query('SELECT * FROM posts')
.stream({highWaterMark: 5})
.pipe(...);
Support for multiple statements is disabled for security reasons (it allows for SQL injection attacks if values are not properly escaped). To use this feature you have to enable it for your connection:
var connection = mysql.createConnection({multipleStatements: true});
Once enabled, you can execute multiple statement queries like any other query:
connection.query('SELECT 1; SELECT 2', function(err, results) {
if (err) throw err;
// `results` is an array with one element for every statement in the query:
console.log(results[0]); // [{1: 1}]
console.log(results[1]); // [{2: 2}]
});
Additionally you can also stream the results of multiple statement queries:
var query = connection.query('SELECT 1; SELECT 2');
query
.on('fields', function(fields, index) {
// the fields for the result rows that follow
})
.on('result', function(row, index) {
// index refers to the statement this result belongs to (starts at 0)
});
If one of the statements in your query causes an error, the resulting Error
object contains a err.index
property which tells you which statement caused
it. MySQL will also stop executing any remaining statements when an error
occurs.
Please note that the interface for streaming multiple statement queries is experimental and I am looking forward to feedback on it.
You can call stored procedures from your queries as with any other mysql driver. If the stored procedure produces several result sets, they are exposed to you the same way as the results for multiple statement queries.
When executing joins, you are likely to get result sets with overlapping column names.
By default, node-mysql will overwrite colliding column names in the order the columns are received from MySQL, causing some of the received values to be unavailable.
However, you can also specify that you want your columns to be nested below the table name like this:
var options = {sql: '...', nestTables: true};
connection.query(options, function(err, results) {
/* results will be an array like this now:
[{
table1: {
fieldA: '...',
fieldB: '...',
},
table2: {
fieldA: '...',
fieldB: '...',
},
}, ...]
*/
});
Or use a string separator to have your results merged.
var options = {sql: '...', nestTables: '_'};
connection.query(options, function(err, results) {
/* results will be an array like this now:
[{
table1_fieldA: '...',
table1_fieldB: '...',
table2_fieldA: '...',
table2_fieldB: '...',
}, ...]
*/
});
This module comes with a consistent approach to error handling that you should review carefully in order to write solid applications.
All errors created by this module are instances of the JavaScript Error object. Additionally they come with two properties:
err.code
: Either a MySQL server error (e.g.'ER_ACCESS_DENIED_ERROR'
), a node.js error (e.g.'ECONNREFUSED'
) or an internal error (e.g.'PROTOCOL_CONNECTION_LOST'
).err.fatal
: Boolean, indicating if this error is terminal to the connection object.
Fatal errors are propagated to all pending callbacks. In the example below, a fatal error is triggered by trying to connect to an invalid port. Therefore the error object is propagated to both pending callbacks:
var connection = require('mysql').createConnection({
port: 84943, // WRONG PORT
});
connection.connect(function(err) {
console.log(err.code); // 'ECONNREFUSED'
console.log(err.fatal); // true
});
connection.query('SELECT 1', function(err) {
console.log(err.code); // 'ECONNREFUSED'
console.log(err.fatal); // true
});
Normal errors however are only delegated to the callback they belong to. So in the example below, only the first callback receives an error, the second query works as expected:
connection.query('USE name_of_db_that_does_not_exist', function(err, rows) {
console.log(err.code); // 'ER_BAD_DB_ERROR'
});
connection.query('SELECT 1', function(err, rows) {
console.log(err); // null
console.log(rows.length); // 1
});
Last but not least: If a fatal errors occurs and there are no pending
callbacks, or a normal error occurs which has no callback belonging to it, the
error is emitted as an 'error'
event on the connection object. This is
demonstrated in the example below:
connection.on('error', function(err) {
console.log(err.code); // 'ER_BAD_DB_ERROR'
});
connection.query('USE name_of_db_that_does_not_exist');
Note: 'error'
are special in node. If they occur without an attached
listener, a stack trace is printed and your process is killed.
tl;dr: This module does not want you to deal with silent failures. You should always provide callbacks to your method calls. If you want to ignore this advice and suppress unhandled errors, you can do this:
// I am Chuck Norris:
connection.on('error', function() {});
This module is exception safe. That means you can continue to use it, even if one of your callback functions throws an error which you're catching using 'uncaughtException' or a domain.
For your convenience, this driver will cast mysql types into native JavaScript types by default. The following mappings exist:
- TINYINT
- SMALLINT
- INT
- MEDIUMINT
- YEAR
- FLOAT
- DOUBLE
- TIMESTAMP
- DATE
- DATETIME
- TINYBLOB
- MEDIUMBLOB
- LONGBLOB
- BLOB
- BINARY
- VARBINARY
- BIT (last byte will be filled with 0 bits as necessary)
- CHAR
- VARCHAR
- TINYTEXT
- MEDIUMTEXT
- LONGTEXT
- TEXT
- ENUM
- SET
- DECIMAL (may exceed float precision)
- BIGINT (may exceed float precision)
- TIME (could be mapped to Date, but what date would be set?)
- GEOMETRY (never used those, get in touch if you do)
It is not recommended (and may go away / change in the future) to disable type casting, but you can currently do so on either the connection:
var connection = require('mysql').createConnection({typeCast: false});
Or on the query level:
var options = {sql: '...', typeCast: false};
var query = connection.query(options, function(err, results) {
});
You can also pass a function and handle type casting yourself. You're given some
column information like database, table and name and also type and length. If you
just want to apply a custom type casting to a specific type you can do it and then
fallback to the default. Here's an example of converting TINYINT(1)
to boolean:
connection.query({
sql: '...',
typeCast: function (field, next) {
if (field.type == 'TINY' && field.length == 1) {
return (field.string() == '1'); // 1 = true, 0 = false
}
return next();
}
});
If you need a buffer there's also a .buffer()
function and also a .geometry()
one
both used by the default type cast that you can use.
If, for any reason, you would like to change the default connection flags, you
can use the connection option flags
. Pass a string with a comma separated list
of items to add to the default flags. If you don't want a default flag to be used
prepend the flag with a minus sign. To add a flag that is not in the default list, don't prepend it with a plus sign, just write the flag name (case insensitive).
Please note that some available flags that are not default are still not supported (e.g.: SSL, Compression). Use at your own risk.
The next example blacklists FOUND_ROWS flag from default connection flags.
var connection = mysql.createConnection("mysql://localhost/test?flags=-FOUND_ROWS");
- LONG_PASSWORD
- FOUND_ROWS
- LONG_FLAG
- CONNECT_WITH_DB
- ODBC
- LOCAL_FILES
- IGNORE_SPACE
- PROTOCOL_41
- IGNORE_SIGPIPE
- TRANSACTIONS
- RESERVED
- SECURE_CONNECTION
- MULTI_RESULTS
- MULTI_STATEMENTS (used if
multipleStatements
option is activated)
- NO_SCHEMA
- COMPRESS
- INTERACTIVE
- SSL
- PS_MULTI_RESULTS
- PLUGIN_AUTH
- SSL_VERIFY_SERVER_CERT
- REMEMBER_OPTIONS
If you are running into problems, one thing that may help is enabling the
debug
mode for the connection:
var connection = mysql.createConnection({debug: true});
This will print all incoming and outgoing packets on stdout. You can also restrict debugging to packet types by passing an array of types to debug:
var connection = mysql.createConnection({debug: ['ComQueryPacket', 'RowDataPacket']});
to restrict debugging to the query and data packets.
If that does not help, feel free to open a GitHub issue. A good GitHub issue will have:
- The minimal amount of code required to reproduce the problem (if possible)
- As much debugging output and information about your environment (mysql version, node version, os, etc.) as you can gather.
Set the environment variables MYSQL_DATABASE
, MYSQL_HOST
, MYSQL_PORT
, MYSQL_USER
and MYSQL_PASSWORD
. (You may want to put these in a config.sh
file and source it when you run the tests). Then run make test
.
For example, if you have an installation of mysql running on localhost:3306 and no password set for the root
user, run:
mysql -u root -e "CREATE DATABASE IF NOT EXISTS node_mysql_test"
MYSQL_HOST=localhost MYSQL_PORT=3306 MYSQL_DATABASE=node_mysql_test MYSQL_USER=root MYSQL_PASSWORD= make test
- Edit the variables in the file
make.bat
according to your system and mysql-settings. - Make sure the database (e.g. 'test') you want to use exists and the user you entered has the proper rights to use the test database. (E.g. do not forget to execute the SQL-command
FLUSH PRIVILEGES
after you have created the user.) - In a DOS-box (or CMD-shell) in the folder of your application run
npm install mysql --dev
or in the mysql folder (node_modules\mysql
), runnpm install --dev
. (This will install additional developer-dependencies for node-mysql.) - Run
npm test mysql
in your applications folder ornpm test
in the mysql subfolder. - If you want to log the output into a file use
npm test mysql > test.log
ornpm test > test.log
.
- Prepared statements
- setTimeout() for Connection / Query
- Support for encodings other than UTF-8 / ASCII
- API support for transactions, similar to php