Knex.js is a "batteries included" SQL query builder for Postgres, MySQL, MariaDB and SQLite3, designed to be flexible, portable, and fun to use. It features both traditional node style callbacks as well as a promise interface for cleaner async flow control, a stream interface, full featured query and schema builders, transaction support, connection pooling and standardized responses between different query clients and dialects.
The project is hosted on GitHub, and the annotated source code is available, and has a comprehensive test suite.
Knex is available for use under the MIT software license.
You can report bugs and discuss features on the GitHub issues page, add pages to the wiki or send tweets to @tgriesser.
Thanks to all of the great contributions to the project.
Special thanks to Taylor Otwell and his work on the Laravel Query Builder, from which much of the builder's code and syntax was originally derived.
Big and exciting improvements from the 0.5 release, the 0.6 release brings refactored internals, streams, the ability to properly inject & bind knex.raw statements throughout any queries, the ability to re-use existing snippets. If you were only using the publicly documented API, no major changes should be necessary. If you notice any issues, please open a ticket. For a full list of changes, see the entry in the change log.
Minor changes from the 0.4.x series, include the fact that aggregate functions are no longer aliased as "aggregate", but rather left as-is, unless explicitly aliased. See this ticket for more info.
Knex can be used as an SQL query builder in both Node.JS and the browser, limited to WebSQL's constraints (like the inability to drop tables or read schemas). Composing SQL queries in the browser for execution on the server is highly discouraged, as this can be the cause of serious security vulnerabilities. The browser builds outside of WebSQL are primarily for learning purposes - for example, you can pop open the console and build queries on this page using the pg, mysql, and sqlite3 objects.
The primary target environment for Knex is Node.js, you will need to install the knex library, and then install the appropriate database library: pg for PostgreSQL, mysql for MySQL or MariaDB, or sqlite3 for SQLite3.
$ npm install knex@0.6.0 --save # Then add one of the following (adding a --save) flag: $ npm install mysql $ npm install mariasql $ npm install pg $ npm install sqlite3
The browser builds and pre-built dependencies can be found in the browser directory. View source on this page to see the browser builds in-action.
The knex module is its self a function which takes a configuration object for Knex, accepting a few parameters. The client parameter is required and determines which client adapter will be used with the library.
var knex = require('knex')({
client: 'mysql',
connection: {
host : '127.0.0.1',
user : 'your_database_user',
password : 'your_database_password',
database : 'myapp_test'
}
});
The connection options are passed directly to the appropriate database client to create the connection, and may be either an object, or a connection string:
var pg = require('knex')({
client: 'pg',
connection: process.env.PG_CONNECTION_STRING
});
Note: When you use the SQLite3 adapter, there is a filename required, not a network connection. For example:
var knex = require('knex')({
client: 'sqlite3',
connection: {
filename: "./mydb.sqlite"
}
});
Initializing the library should normally only ever happen once in your application, as it creates a connection pool for the current database, you should use the instance returned from the initialize call throughout your library.
Passing a debug: true flag on your initialization object will.
The client created by the configuration initializes a connection pool, using the generic-pool-redux library. This connection pool has a default setting of a min: 2, max: 10 for the MySQL and PG libraries, and a single connection for sqlite3 (due to issues with utilizing multiple connections on a single file). To change the config settings for the pool, pass a pool option as one of the keys in the initialize block.
var knex = require('knex')({
client: 'mysql',
connection: {
host : '127.0.0.1',
user : 'your_database_user',
password : 'your_database_password',
database : 'myapp_test'
},
pool: {
min: 0,
max: 7
}
});
For convenience, the any migration configuration may be specified when initializing the library. Read the Migrations section for more information.
var knex = require('knex')({
client: 'mysql',
connection: {
host : '127.0.0.1',
user : 'your_database_user',
password : 'your_database_password',
database : 'myapp_test'
},
migrations: migrationConfig
});
The heart of the library, the knex query builder is the interface used for building and executing standard SQL queries, such as select, insert, update, delete.
knexknex(tableName) / knex.[methodName]
The query builder starts off either by specifying a tableName you wish to query against,
or by calling any method directly on the knex object. This kicks off a jQuery-like chain, with which
you can call additional query builder methods as needed to construct the query, eventually calling any of the
interface methods, to either convert toString, or execute the
query with a promise, callback, or stream.
select.select([*columns])
Creates a select query, taking an optional array of columns for the query, eventually
defaulting to * if none are specified when the query is built. The response of a select call will
resolve with an array of objects selected from the database.
knex.select('title', 'author', 'year').from('books')
knex.select().table('books')
column.column(columns)
Specifically set the columns to be selected on a select query, taking an array or a list of of column names.
knex.column('title', 'author', 'year').select().from('books')
knex.column(['title', 'author', 'year']).select().from('books')
from.from([tableName])
Alias: into, table
Specifies the table used in the current query, replacing the current table name if
one has already been specified. This is typically used in the sub-queries performed
in the advanced where or union methods.
knex.select('*').from('users')
Several methods exist to assist in dynamic where clauses. In many places functions may be used in place of values, constructing subqueries. In most places existing knex queries may be used to compose sub-queries, etc. Take a look at a few of the examples for each method for instruction on use:
where.where(~mixed~)
Object Syntax:
knex('users').where({ first_name: 'Test', last_name: 'User' }).select('id')
Key, Value:
knex('users').where('id', 1)
Grouped Chain:
knex('users').where(function() { this.where('id', 1).orWhere('id', '>', 10) }).orWhere({name: 'Tester'})
Operator:
knex('users').where('votes', '>', 100)
var subquery = knex('users').where('votes', '>', 100).andWhere('status', 'active').orWhere('name', 'John').select('id'); knex('accounts').where('id', 'in', subquery)
whereIn.whereIn(column, array|callback|builder) / .orWhereIn
Shorthand for .where('id', 'in', obj), the .whereIn and .orWhereIn methods add a "where in" clause
to the query. Click the "play" button below to see the queries.
knex.select('name').from('users') .whereIn('id', [1, 2, 3]) .orWhereIn('id', [4, 5, 6])
knex.select('name').from('users') .whereIn('account_id', function() { this.select('id').from('accounts'); })
var subquery = knex.select('id').from('accounts'); knex.select('name').from('users') .whereIn('account_id', subquery)
knex('users') .where('name', '=', 'John') .orWhere(function() { this.where('votes', '>', 100).andWhere('title', '<>', 'Admin'); })
whereNotIn.whereNotIn(column, array|callback|builder) / .orWhereNotIn
knex('users').whereNotIn('id', [1, 2, 3])
knex('users').where('name', 'like', '%Test%').orWhereNotIn('id', [1, 2, 3])
whereNull.whereNull(column) / .orWhereNotNull
knex('users').whereNull('updated_at')
whereNotNull.whereNotNull(column) / .orWhereNotNull
knex('users').whereNotNull('created_at')
whereExists.whereExists(callback) / .orWhereExists
knex('users').whereExists(function() { this.select('*').from('accounts').where('users.account_id', '=', 'accounts.id'); })
whereNotExists.whereNotExists() / .orWhereNotExists
knex('users').whereNotNull('created_at')
whereBetween.whereBetween(column, range) / .orWhereBetween
knex('users').whereBetween('votes', [1, 100])
whereNotBetween.whereNotBetween(column, range) / .orWhereNotBetween
knex('users').whereNotBetween('votes', [1, 100])
whereRaw.whereRaw(query, [bindings])
Convenience helper for .where(knex.raw(query)).
knex('users').whereRaw('id = ?', [1])
Several methods are provided which assist in building
join.join(table, first, [operator], second)
The join builder can be used to specify joins between tables,
with the first argument being the joining table, the next three arguments
being the first join column, the join operator and the second
join column, respectively.
knex('users') .join('contacts', 'users.id', '=', 'contacts.user_id') .select('users.id', 'contacts.phone')
knex('users') .join('contacts', 'users.id', 'contacts.user_id') .select('users.id', 'contacts.phone')
For grouped joins, specify a function as the second argument for the join query, and use on and orOn to create joins that are grouped with parentheses.
knex.select('*').from('users').join('accounts', function() { this.on('accounts.id', '=', 'users.account_id').orOn('accounts.owner_id', '=', 'users.id') })
innerJoin.innerJoin(column, ~mixed~)
knex.from('users').innerJoin('accounts', 'users.id', 'accounts.user_id')
knex.table('users').innerJoin('accounts', 'users.id', '=', 'accounts.user_id')
knex('users').innerJoin('accounts', function() { this.on('accounts.id', '=', 'users.account_id').orOn('accounts.owner_id', '=', 'users.id') })
leftJoin.leftJoin(column, ~mixed~)
knex.select('*').from('users').leftJoin('accounts', 'users.id', 'accounts.user_id')
knex.select('*').from('users').leftJoin('accounts', function() { this.on('accounts.id', '=', 'users.account_id').orOn('accounts.owner_id', '=', 'users.id') })
leftOuterJoin.leftOuterJoin(column, ~mixed~)
knex.select('*').from('users').leftOuterJoin('accounts', 'users.id', 'accounts.user_id')
knex.select('*').from('users').leftOuterJoin('accounts', function() { this.on('accounts.id', '=', 'users.account_id').orOn('accounts.owner_id', '=', 'users.id') })
rightJoin.rightJoin(column, ~mixed~)
knex.select('*').from('users').rightJoin('accounts', 'users.id', 'accounts.user_id')
knex.select('*').from('users').rightJoin('accounts', function() { this.on('accounts.id', '=', 'users.account_id').orOn('accounts.owner_id', '=', 'users.id') })
rightOuterJoin.rightOuterJoin(column, ~mixed~)
knex.select('*').from('users').rightOuterJoin('accounts', 'users.id', 'accounts.user_id')
knex.select('*').from('users').rightOuterJoin('accounts', function() { this.on('accounts.id', '=', 'users.account_id').orOn('accounts.owner_id', '=', 'users.id') })
outerJoin.outerJoin(column, ~mixed~)
knex.select('*').from('users').outerJoin('accounts', 'users.id', 'accounts.user_id')
knex.select('*').from('users').outerJoin('accounts', function() { this.on('accounts.id', '=', 'users.account_id').orOn('accounts.owner_id', '=', 'users.id') })
fullOuterJoin.fullOuterJoin(column, ~mixed~)
knex.select('*').from('users').fullOuterJoin('accounts', 'users.id', 'accounts.user_id')
knex.select('*').from('users').fullOuterJoin('accounts', function() { this.on('accounts.id', '=', 'users.account_id').orOn('accounts.owner_id', '=', 'users.id') })
crossJoin.crossJoin(column, ~mixed~)
knex.select('*').from('users').crossJoin('accounts', 'users.id', 'accounts.user_id')
knex.select('*').from('users').crossJoin('accounts', function() { this.on('accounts.id', '=', 'users.account_id').orOn('accounts.owner_id', '=', 'users.id') })
distinct.distinct()
Sets a distinct clause on the query.
// select distinct 'first_name' from customers knex('customers') .distinct('first_name', 'last_name') .select()
groupBy.groupBy(*names)
Adds a group by clause to the query.
knex('users').groupBy('count')
orderBy.orderBy(column, [direction])
Adds an order by clause to the query.
knex('users').orderBy('name', 'desc')
having.having(column, operator, value)
Adds a having clause to the query.
knex('users') .groupBy('count') .orderBy('name', 'desc') .having('count', '>', 100)
havingRaw.havingRaw(column, operator, value)
Adds a havingRaw clause to the query.
knex('users') .groupBy('count') .orderBy('name', 'desc') .havingRaw('count > ?', [100])
offset.offset(value)
Adds an offset clause to the query.
knex.select('*').from('users').offset(10)
limit.limit(value)
Adds a limit clause to the query.
knex.select('*').from('users').limit(10).offset(30)
union.union(query)
Creates a union query, taking a callback to build the union statement.
knex.select('*').from('users').whereNull('last_name').union(function() { this.select('*').from('users').whereNull('first_name'); })
unionAll.unionAll(query)
Creates a union all query, with the same method signature as
the union method.
knex.select('*').from('users').whereNull('last_name').unionAll(function() { this.select('*').from('users').whereNull('first_name'); })
insert.insert(data, [returning])
Creates an insert query, taking either a hash of properties to be inserted into the row, or
an array of inserts, to be executed as a single insert command. Resolves the promise / fulfills the callback
with an array containing the first insert id of the inserted model, or an array containing all inserted ids
for postgresql.
// Returns [1] in "mysql", "sqlite"; [] in "postgresql" unless the 'returning' parameter is set. knex('books').insert({title: 'Slaughterhouse Five'})
// Normalizes for empty keys on multi-row insert: knex('coords').insert([{x: 20}, {y: 30}, {x: 10, y: 20}])
// Returns [2] in "mysql", "sqlite"; [2, 3] in "postgresql" knex.insert([{title: 'Great Gatsby'}, {title: 'Fahrenheit 451'}], 'id').into('books')
returning.returning(column)
Only utilitzed by PostgreSQL databases, the returning method specifies which column should be returned
by the insert method.
// Returns [1] knex('books') .returning('id') .insert({title: 'Slaughterhouse Five'})
// Returns [2] in "mysql", "sqlite"; [2, 3] in "postgresql" knex('books') .returning('id') .insert([{title: 'Great Gatsby'}, {title: 'Fahrenheit 451'}])
update.update(data, [returning]) / .update(key, value, [returning])
Creates an update query, taking a hash of properties or a key/value pair
to be updated based on the other query constraints. Resolves the promise / fulfills the
callback with the number of affected rows for the query.
knex('books') .where('published_date', '<', 2000) .update({ status: 'archived' })
// Returns [1] in "mysql", "sqlite"; [] in "postgresql" unless the 'returning' parameter is set. knex('books').update('title', 'Slaughterhouse Five')
del / delete.del()
Aliased to del as delete is a reserved word in javascript, this method deletes
one or more rows, based on other conditions specified in the query. Resolves the promise / fulfills the
callback with the number of affected rows for the query.
knex('accounts') .where('activated', false) .del()
transacting.transacting(transactionObj)
Used by knex.transaction, the transacting method may be chained to any
query and passed the object you wish to join the query as part of the transaction for.
var Promise = require('bluebird');
knex.transaction(function(trx) {
knex('books').transacting(t).insert({name: 'Old Books'})
.then(function(id) {
return someExternalMethod(t);
})
.then(t.commit)
.then(t.rollback);
}).then(function(resp) {
console.log('Transaction complete.');
}).catch(function(err) {
console.error(err);
});
forUpdate.transacting(t).forUpdate()
Dynamically added after a transaction is specified,
the forUpdate adds a FOR UPDATE in PostgreSQL and MySQL during a select statement.
knex('tableName') .transacting(trx) .forUpdate() .select('*')
knex('tableName') .transacting(trx) .forShare() .select('*')
count.count(column)
Performs a count on the specified column.
knex('users').count('active')
knex('users').count('active as a')
min.min(column)
Gets the minimum value for the specified column.
knex('users').min('age')
knex('users').min('age as a')
max.max(column)
Gets the maximum value for the specified column.
knex('users').max('age')
knex('users').max('age as a')
sum.sum(column)
Retrieve the sum of the values of a given column.
knex('users').sum('products')
knex('users').sum('products as p')
avg.avg(column)
Retrieve the average of the values of a given column.
knex('users').avg('age')
knex('users').avg('age as a')
increment.increment(column, amount)
Increments a column value by the specified amount.
knex('accounts') .where('userid', '=', 1) .increment('balance', 10)
decrement.decrement(column, amount)
Decrements a column value by the specified amount.
knex('accounts').where('userid', '=', 1).decrement('balance', 5)
truncate.truncate()
Truncates the current table.
knex('accounts').truncate()
pluck.pluck(id)
This will pluck the specified column from each row in your results, yielding a promise which resolves
to the array of values selected.
knex.table('users').pluck('id').then(function(ids) {
console.log(ids);
});
columnInfo.columnInfo([columnName])
Returns an object with the column info about the current table, or an individual column if one is passed, returning an object with the following keys:
knex('users').columnInfo().then(function(info) {
// ...
});
debug.debug()
Turns on debugging for the current query chain.
connection.connection(dbConnection)
Explicitly specify the connection for the query, allowing you to use the knex chain outside of
the built-in pooling capabilities.
options.options()
Allows for mixing in additional options as defined by database client specific libraries:
knex('accounts as a1')
.leftJoin('accounts as a2', function() {
this.on('a1.email', '<>', 'a2.email');
})
.select(['a1.email', 'a2.email'])
.where(knex.raw('a1.id = 1'))
.option({ nestTables: true, rowMode: 'array' })
.limit(2)
.then(...
Transactions are an important feature of relational databases, as they allow correct recovery from failures and keep a database consistent even in cases of system failure. All queries within a transaction are executed on the same database connection, and run the entire set of queries as a single unit of work. Any failure will mean the database will rollback any queries executed on that connection to the pre-transaction state.
Transactions are handled by passing a handler function into knex.transaction. The handler function accepts a single argument, the an object which may be used in two ways:
var Promise = require('bluebird');
// Using trx as a query builder:
knex.transaction(function(trx) {
var books = [
{title: 'Canterbury Tales'},
{title: 'Moby Dick'},
{title: 'Hamlet'}
];
return trx
.insert({name: 'Old Books'})
.into('catalogues')
.then(function(row) {
return Promise.map(books, function(book) {
book.catalogue_id = row.id;
// Some validation could take place here.
return trx.insert(info).into('books');
}));
});
})
.then(function(inserts) {
console.log(inserts.length + ' new books saved.');
})
.catch(function(error) {
// If we get here, that means that neither the 'Old Books' catalogues insert,
// nor any of the books inserts will have taken place.
console.error(error);
});
And then this example:
var Promise = require('bluebird');
// Using trx as a transaction object:
knex.transaction(function(trx) {
var books = [
{title: 'Canterbury Tales'},
{title: 'Moby Dick'},
{title: 'Hamlet'}
];
knex.insert({name: 'Old Books'})
.into('catalogues')
.transacting(trx)
.then(function(row) {
return Promise.map(books, function(book) {
book.catalogue_id = row.id;
// Some validation could take place here.
return knex.insert(info).into('books').transacting(trx);
}));
})
.then(trx.commit)
.then(trx.rollback);
})
.then(function(inserts) {
console.log(inserts.length + ' new books saved.');
})
.catch(function(error) {
// If we get here, that means that neither the 'Old Books' catalogues insert,
// nor any of the books inserts will have taken place.
console.error(error);
});
Notice that if a promise is not returned within the handler, it is up to you to ensure trx.commit, or trx.rollback are called, otherwise the transaction connection will hang.
createTableknex.schema.createTable(tableName, callback)
Creates a new table on the database, with a callback function to modify the table's
structure, using the schema-building commands.
knex.schema.createTable('users', function (table) { table.increments(); table.string('name'); table.timestamps(); })
renameTableknex.schema.renameTable(from, to)
Renames a table from a current tableName to another.
knex.schema.renameTable('users', 'old_users')
dropTableknex.schema.dropTable(tableName)
Drops a table, specified by tableName.
knex.schema.dropTable('users')
hasTableknex.schema.hasTable(tableName)
Checks for a table's existence by tableName, resolving with a boolean to
signal if the table exists.
knex.schema.hasTable('users').then(function(exists) {
if (!exists) {
return knex.schema.createTable('users', function(t) {
t.increments('id').primary();
t.string('first_name', 100);
t.string('last_name', 100);
t.text('bio');
});
}
});
hasColumnknex.schema.hasColumn(tableName, columnName)
Checks if a column exists in the current table, resolves the promise with a boolean, true
if the column exists, false otherwise.
dropTableIfExistsknex.schema.dropTableIfExists(tableName)
Drops a table conditionally if the table exists, specified by tableName.
knex.schema.dropTableIfExists('users')
tableknex.schema.table(tableName, callback)
Chooses a database table, and then modifies the table, using the Schema Building
functions inside of the callback.
knex.schema.table('users', function (table) { table.dropColumn('name'); table.string('first_name'); table.string('last_name'); })
dropColumntable.dropColumn(name)
Drops a column, specified by the column's name
dropColumnstable.dropColumns(*columns)
Drops multiple columns, taking a variable number of column names.
renameColumntable.renameColumn(from, to)
Renames a column from one name to another.
incrementstable.increments(name)
Adds an auto incrementing column, in PostgreSQL this is a serial. This will be used as the primary key for the column. Also available is a bigIncrements if you wish to add a bigint incrementing number (in PostgreSQL bigserial).
integertable.integer(name)
Adds an integer column.
bigIntegertable.bigInteger(name)
In MySQL or PostgreSQL, adds a bigint column,
otherwise adds a normal integer.
texttable.text(name, [textType])
Adds a text column, with optional textType for MySql text datatype preference.
textType may be mediumtext or longtext, otherwise defaults to text.
stringtable.string(name, [length])
Adds a string column, with optional length defaulting to 255.
floattable.float(column, [precision], [scale])
Adds a float column, with optional precision and scale.
decimaltable.decimal(column, [precision], [scale])
Adds a decimal column, with optional precision and scale.
booleantable.boolean(name)
Adds a boolean column.
datetable.date(name)
Adds a date column.
dateTimetable.dateTime(name)
Adds a dateTime column.
timetable.time(name)
Adds a time column.
timestamptable.timestamp(name, [standard])
Adds a timestamp column, defaults to timestamptz in PostgreSQL, unless true
is passed as the second argument.
timestampstable.timestamps()
Adds a created_at and updated_at column on the database,
setting these each to dateTime types.
binarytable.binary(name)
Adds a binary column.
enum / enutable.enu(col, values)
Adds a enum column, (aliased to enu, as enum is a reserved word in javascript).
jsontable.json(name)
Adds a json column, using the built-in json type in postgresql, defaulting to a text column
in older versions of postgresql or in unsupported databases.
uuidtable.uuid(name)
Adds a uuid column - this uses the built-in uuid type in postgresql, and falling back to a
char(36) in other databases.
commenttable.comment(value)
Sets the comment for a table.
enginetable.engine(val)
Sets the engine for the database table, only available within a createTable call, and only
applicable to MySQL.
charsettable.charset(val)
Sets the charset for the database table, only available within a createTable call, and only
applicable to MySQL.
collatetable.collate(val)
Sets the collation for the database table, only available within a createTable call, and only
applicable to MySQL.
specificTypetable.specificType(column, value)
Sets a specific type for the column creation, if you'd like to add a column type that isn't supported here.
The following three methods may be chained on the schema building methods, as modifiers to the column.
indexcolumn.index()
Specifies an field as an index. No-op if this is chained off of a field that cannot be indexed.
primarycolumn.primary()
Sets the field as the primary key for the table.
To create a compound primary key, pass an array of column names: table.primary(['column1', 'column2'])
.
uniquecolumn.unique()
Sets the column as unique.
referencescolumn.references(column)
Sets the "column" that the current column references as a foreign key.
inTablecolumn.inTable(table)
Sets the "table" where the foreign key column is located.
onDeletecolumn.onDelete(command)
Sets the SQL command to be run "onDelete".
onUpdatecolumn.onUpdate(command)
Sets the SQL command to be run "onUpdate".
defaultTocolumn.defaultTo(value)
Sets the default value for the column on an insert.
unsignedcolumn.unsigned()
Specifies an integer as unsigned. No-op if this is chained off of a non-integer field.
notNullablecolumn.notNullable()
Adds a not null on the current column being created.
nullablecolumn.nullable()
Default on column creation, this explicitly sets a field to be nullable.
aftercolumn.after(field)
Sets the column to be inserted after another, only used in MySQL alter tables.
commentcolumn.comment(value)
Sets the comment for a column.
knex.schema.createTable('accounts', function() { t.increments().primary(); t.string('email').unique(); });
Sometimes you may need to use a raw expression in a query. Raw query object may be injected pretty much anywhere you want, and using proper bindings can ensure your values are escaped properly, preventing SQL-injection attacks.
Raw expressions are created by using knex.raw(sql, [bindings]) and passing this as a value for any value in the query chain.
knex('users') .select(knex.raw('count(*) as user_count, status')) .where(knex.raw(1)) .orWhere(knex.raw('status <> ?', [1])) .groupBy('status')
The knex.raw may also be used to build a full query and execute it, as a standard query builder query would be executed. The benefit of this is that it uses the connection pool and provides a standard interface for the different client libraries.
knex.raw('select * from users where id = ?', [1]).then(function(resp) {
...
});
Note that the response will be whatever the underlying sql library would typically return on a normal query, so you may need to look at the documentation for the base library the queries are executing against to determine how to handle the response.
Knex.js provides several options to deal with query output. The following methods are present on the query builder, schema builder, and the raw builder:
Promises are the preferred way of dealing with queries in knex, as they allow you to return values from a fulfillment handler, which in turn become the value of the promise. The main benefit of promises are the ability to catch thrown errors without crashing the node app, making your code behave like a .try / .catch / .finally in synchronous code.
knex.select('name').from('users')
.where('id', '>', 20)
.andWhere('id', '<', 200)
.limit(10)
.offset(x)
.then(function(rows) {
return _.pluck(rows, 'name');
})
.then(function(names) {
return knex.select('id').from('nicknames').whereIn('nickname', names);
})
.then(function(rows) {
console.log(rows);
})
.catch(function(error) {
console.error(error)
});
then.then(onFulfilled)
Coerces the current query builder chain into a promise state, accepting the resolve
and reject handlers as specified by the Promises/A+ spec.
As stated in the spec, more than one call to the then method for the current query chain will resolve
with the same value, in the order they were called; the query will not be executed multiple times.
knex.select('*').from('users').where({name: 'Tim'})
.then(function(rows) {
return knex.insert({user_id: rows[0].id, name: 'Test'}, 'id').into('accounts');
}).then(function(id) {
console.log('Inserted Account ' + id);
}).catch(function(error) {
console.error(error);
});
catch.catch(onRejected)
Coerces the current query builder into a promise state, catching any error thrown by the query, the same as calling .then(null, onRejected).
return knex.insert({id: 1, name: 'Test'}, 'id').into('accounts')
.catch(function(error) {
console.error(error);
}).then(function() {
return knex.select('*').from('accounts').where('id', 1);
}).then(function(rows) {
console.log(rows[0]);
}).catch(function(error) {
console.error(error);
});
tap.tap(sideEffectHandler)
Executes side effects on the resolved response, ultimately returning a promise that fulfills with the original
value. A thrown error or rejected promise will cause the promise to transition into a rejected state.
// Using only .then()
query.then(function(x) {
doSideEffectsHere(x);
return x;
});
// Using .tap()
promise.tap(doSideEffectsHere);
map.map(mapper)
A passthrough to Bluebird's map implementation with the result set.
knex.select('name').from('users').limit(10).map(function(row) {
return row.name;
}).then(function(names) {
console.log(names);
}).catch(function(e) {
console.error(e);
});
reduce.reduce(reducer, [initialValue])
A passthrough to Bluebird's reduce implementation with the result set.
knex.select('name').from('users').limit(10).reduce(function(memo, row) {
memo.names.push(row.name);
memo.count++;
return memo;
}, {count: 0, names: []}).then(function(obj) {
console.log(obj);
}).catch(function(e) {
console.error(e);
});
bind.bind(context)
A passthrough to Bluebird's bind method which sets the context value (this) for the returned promise.
knex.select('name').from('users')
.limit(10)
.bind(console)
.then(console.log)
.catch(console.error)
return.return(value)
Shorthand for calling .then(function() { return value }).
// Without return:
knex.insert(values).into('users')
.then(function() {
return {inserted: true};
});
knex.insert(values).into('users').return({inserted: true});
exec.exec(callback)
If you'd prefer a callback interface over promises, the exec function
accepts a standard node style callback for executing the query chain. Note that as
with the then method, subsequent calls to the same
query chain will return the same result.
knex.select('name').from('users')
.where('id', '>', 20)
.andWhere('id', '<', 200)
.limit(10)
.offset(x)
.exec(function(err, rows) {
if (err) return console.error(err);
knex.select('id').from('nicknames').whereIn('nickname', _.pluck(rows, 'name'))
.exec(function(err, rows) {
if (err) return console.error(err);
console.log(rows);
});
});
Streams are a powerful way of piping data through as it comes in, rather than all at once. You can read more about streams here at substack's stream handbook. See the following for example uses of stream & pipe. If you wish to use streams with PostgreSQL, you must also install the pg-query-stream module.
stream.stream([options], [callback])
If called with a callback, the callback is passed the stream and a promise is returned. Otherwise,
the readable stream is returned.
// Retrieve the stream:
var stream = knex.select('*').from('users').stream();
stream.pipe(writableStream);
// With options:
var stream = knex.select('*').from('users').stream({highWaterMark: 5});
stream.pipe(writableStream);
// Use as a promise:
var stream = knex.select('*').from('users').where(knex.raw('id = ?', [1])).stream(function(stream) {
stream.pipe(writableStream);
}).then(function() {
// ...
}).catch(function(e) {
console.error(e);
});
pipe.pipe(writableStream)
Pipe a stream for the current query to a writableStream.
var stream = knex.select('*').from('users').pipe(writableStream);
query
A query event is fired just before a query takes place, providing data about the query, including the connection's __cid property and any other information about the query as described in toSQL. Useful for logging all
knex.select('*')
.from('users')
.on('query', function(data) {
app.log(data);
})
.then(function() {
// ...
});
toString.toString()
Returns an array of query strings filled out with the
correct values based on bindings, etc. Useful for debugging.
knex.select('*').from('users').where(knex.raw('id = ?', [1])).toString()
toSQL.toSQL()
Returns an array of query strings filled out with the
correct values based on bindings, etc. Useful for debugging.
knex.select('*').from('users').where(knex.raw('id = ?', [1])).toSQL()
// Ouputs:
{
bindings: [1],
method: 'select',
sql: 'select * from "users" where id = ?',
options: undefined,
}
Migrations allow for you to define sets of schema changes so upgrading a database is a breeze.
The migration CLI is stored in a separate repository and is driven by the node-liftoff module. Running:
$ knex init
will create a sample knexfile.js - the file which contains our various database configurations. Once you have a knexfile.js, you can use the migration tool to create migration files to the specified directory (default migrations). Creating new migration files can be achieved by running:
$ knex migrate:make migration_name
Once you have the migrations in place you wish to run, you can run:
$ knex migrate:latest
To update your database to the latest version.
A knexfile.js or knexfile.coffee generally contains all of the configuration for your database, for each environment you will be using. You may pass a --knexfile option to any of the command line statements to specify an alternate path to your knexfile.
knex.migrate is the class utilized by the knex migrations cli. Each method takes an optional config object, which may specify specifies the database, directory, and tableName for the migrations. Check here for more information about the migration CLI tool.
makeknex.migrate.make(name, [config])
Creates a new migration, with the name of the migration being added.
latestknex.migrate.latest([config])
Runs all migrations that have not yet been run.
rollbackknex.migrate.rollback([config])
Rolls back the latest migration group.
currentVersionknex.migrate.currentVersion([config])
Retrieves and returns the current migration version, as a promise.
If there aren't any migrations run yet, returns "none" as the value for the currentVersion.
Have questions about the library? Come join us in the #bookshelf freenode IRC channel for support on knex.js and bookshelf.js, or post an issue on Stack Overflow or in the GitHub issue tracker.
How do I help contribute?
Glad you ask! Pull requests, or feature requests, though not always implemented, are a great way
to help make Knex even better than it is now. If you're looking for something specific to help out with,
there's a number of unit tests that aren't implemented yet, the library could never have too many of those.
If you want to submit a fix or feature, take a look at the
Contributing readme in the Github and go ahead and open a ticket.
How do I debug?
If you pass {debug: true} as one of the options in your initialize settings, you can see all of the query calls being made. Sometimes you need to dive a bit further into the various calls and see what all is going on behind the scenes. I'd recommend
node-inspector, which allows you to debug code with debugger statements like you would in the browser.
At the start of your application code will catch any errors not otherwise caught in the normal promise chain handlers, which is very helpful in debugging.
How do I run the test suite?
The test suite looks for an environment variable called KNEX_TEST for the path to the database
configuration. If you run the following command:
$ export KNEX_TEST='/path/to/your/knex_config.js' $ npm test
replacing with the path to your config file, and the config file is valid, the test suite should run properly.
Can I use Knex outside of Node.js
Yes. While the WebSQL spec is deprecated, there is still an adapter that provides support.
Checkout the browser builds for more details.
0.6.0 — June 4, 2014
Major Library refactor. Notable changes & fixes include:
0.5.15 — June 4, 2014 — Diff
Dropped indexes feature now functions correctly, (#278).
0.5.14 — May 6, 2014 — Diff
Remove the charset encoding if it's utf8 for mysql, as it's the default but also
currently causes some issues in recent versions of node-mysql.
0.5.13 — April 2, 2014 — Diff
Fix regression in array bindings for postgresql (#228).
0.5.12 — Mar 31, 2014 — Diff
Add more operators for where clauses, including && (#226).
0.5.11 — Mar 25, 2014 — Diff
0.5.10 — Mar 19, 2014 — Diff
Add the .exec method to the internal promise shim.
0.5.9 — Mar 18, 2014 — Diff
Remove error'ed connections from the connection pool (#206), added support for node-postgres-pure (pg.js) (#200).
0.5.8 — Feb 27, 2014 — Diff
Fix for chaining on forUpdate / forShare, adding map & reduce from bluebird.
0.5.7 — Feb 18, 2014 — Diff
Fix for a null limit / offset breaking query chain (#182).
0.5.6 — Feb 5, 2014 — Diff
Bump bluebird dependency to ~1.0.0, fixing regression in Bluebird 1.0.2 (#176).
0.5.5 — Jan 28, 2014 — Diff
0.5.4 — Jan 7, 2014 — Diff
Fix for using raw statements in defaultTo schema builder methods (#146).
0.5.3 — Jan 2, 2014 — Diff
Fix for incorrectly formed sql when aggregates are used with columns (#144).
0.5.2 — Dec 18, 2013 — Diff
Adding passthrough "catch", "finally" to bluebird implementations, use
bluebird's "nodeify" internally for exec.
0.5.1 — Dec 12, 2013 — Diff
0.5.0 — Nov 25, 2013 — Diff — Docs
0.4.13 — Oct 31, 2013 — Diff
Fix for aggregate methods on toString and clone, (#98).
0.4.12 — Oct 29, 2013 — Diff
Fix incorrect values passed to float in MySQL and decimal
in PostgreSQL.
0.4.11 — Oct 15, 2013 — Diff
Fix potential sql injection vulnerability in orderBy, thanks to @sebgie.
0.4.10 — Oct 14, 2013 — Diff
0.4.9 — Oct 7, 2013 — Diff
0.4.8 — Oct 2, 2013 — Diff
Connections are no longer pushed back into the pool if they never existed to begin with (#85).
0.4.7 — Sep 27, 2013 — Diff
The column is now a documented method on the builder api, and takes either an individual column or an array of columns to select.
0.4.6 — Sep 25, 2013 — Diff
Standardizing handling of errors for easier debugging, as noted in (#39).
0.4.5 — Sep 24, 2013 — Diff
Fix for hasTable always returning true in MySQL (#82), fix where sql queries were duplicated with multiple calls on toSql with the
schema builder.
0.4.4 — Sep 22, 2013 — Diff
Fix for debug method not properly debugging individual queries.
0.4.3 — Sep 18, 2013 — Diff
Fix for underscore not being defined in various grammar files.
0.4.2 — Sep 17, 2013 — Diff
Fix for an error being thrown when an initialized ClientBase instance was passed into Knex.initialize. pool.destroy now optionally accepts a callback to notify when it has completed draining and destroying all connections.
0.4.1 — Sep 16, 2013 — Diff
Cleanup from the 0.4.0 release, fix a potential exploit in "where" clauses pointed out by Andri Möll, fix for clients
not being properly released from the pool #70, fix for where("foo", "<>", null) doing an "IS NULL" statement.
0.4.0 — Sep 13, 2013 — Diff — Docs
Breaking Changes:
0.2.6 — Aug 29, 2013 — Diff — Docs
Reject the transaction promise if the transaction "commit" fails, (#50).
0.2.5 — Aug 25, 2013
Fix error if a callback isn't specified for exec, (#49).
0.2.4 — Aug 22, 2013
Fix SQLite3 delete not returning affected row count, (#45).
0.2.3 — Aug 22, 2013
Fix insert with default values in PostgreSQL and SQLite3, (#44).
0.2.2 — Aug 20, 2013
Allowing Raw queries to be passed as the primary table names.
0.2.1 — Aug 13, 2013
Fix for an array passed to insert being mutated.
0.2.0 — Aug 7, 2013
Breaking changes:
0.1.8 — July 7, 2013
Somehow missing the != operator. Using _.find rather than _.where in getCommandsByName(#22).
0.1.7 — June 12, 2013
Ensures unhandled errors in the exec callback interface are re-thrown.
0.1.6 — June 9, 2013
Renaming beforeCreate to afterCreate. Better handling of errors in the connection pooling.
0.1.5 — June 9, 2013
Added the ability to specify beforeCreate and beforeDestroy hooks on the initialize's options.pool
to perform any necessary database setup/teardown on connections before use (#14). where and having
may now accept Knex.Raw instances, for consistency (#15). Added an orHaving method to the builder.
The ability to specify bindings on Raw queries has been removed.
0.1.4 — May 22, 2013
defaultTo now accepts "false" for boolean columns, allows for empty strings as default values.
0.1.3 — May 18, 2013
Enabling table aliases (#11). Fix for issues with transactions not functioning (#12).
0.1.2 — May 15, 2013
Bug fixes for groupBy (#7). Mysql using collation, charset config settings in createTable.
Added engine on schemaBuilder specifier (#6). Other doc fixes, tests.
0.1.1 — May 14, 2013
Bug fixes for sub-queries, minor changes to initializing "main" instance, adding "pg" as
a valid parameter for the client name in the connection settings.
0.1.0 — May 13, 2013
Initial Knex release.