Knex.js is a query builder for Postgres, MySql 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, full featured query and schema builders, transaction support, connection pooling and node.js adapters for postgres, mysql, and sqlite3 - standardizing responses between the three.
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, post questions to the Google Group, add pages to the wiki or send tweets to @tgriesser.
Special thanks to Taylor Otwell and his work on the Laravel Query Builder, from which much of the code and syntax is derived.
All dependencies are specified in package.json file but include underscore.js, when.js, and the generic-pool library. You then need to install either mysql, pg, or sqlite3 from npm if you wish to use one of these databases with node.js, or create your own client adapter and specify it in Knex.Initialize.
$ npm install knex # Then add one of the following: $ npm install mysql $ npm install pg $ npm install sqlite3
Knex.Initialize is the initializing function that must be called prior to using Knex, accepting a few parameters. The client parameter is required and determines which client adapter will be used with the library.
Knex.Initialize({ client: 'mysql', connection: { host : '127.0.0.1', user : 'your_database_user', password : 'your_database_password', database : 'myapp_test', charset : 'utf8' } });
It is also possible to use Knex with multiple database connection instances if you'd like, by creating named instances. To do this, pass the name of the connection as the first parameter into Knex.Initialize and it will return that instance, which may also be referenced by name under Knex.Instances.
var SqliteDB = Knex.Initialize('sqlitedb', { client: 'sqlite', connection: { database : './testdb' } }); var MySql2 = Knex.Initialize('mysql2', { client: 'mysql', connection: { ... } }); // Knex.Instances['mysql2'] === MySql2; // Knex.Instances['sqlitedb'] === SqliteDB; MySql2('accounts') .select() .then(function(resp) { // ... }); SqliteDB('users') .insert({email: 'test@email.com'}) .exec(function(err, resp) { // ... });
The Knex.Builder is the interface used for building and executing standard SQL queries, such as select, insert, update, delete. The query is run by specifying a tableName, adding additional query parameters, and executing the query with one of the public interface methods.
KnexKnex(tableName)...
The Knex query builder starts off by specifying a tableName you wish to query against,
which returns a chainable interface, similar to a jQuery chain. You can then call any additional
query builder methods needed to construct the query, eventually calling either
then or exec, to execute the query with a
promise or a callback, respectively.
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
return with the
// select "title", "author", "year" from "books" Knex('books').select('title', 'author', 'year'); // select * from "books" Knex('books').select();
from.from([tableName])
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.
where.where(~dynamic~)
There are several helpers for creating dynamic where clauses on queries. Take a look at a few
examples to see how these may be mixed and matched to create fluent constraints on the query.
// Basic Uses: // objects Knex('users').where({ first_name: 'Test', last_name: 'User' }).select('id').then(... // key, value Knex('users').where('id', 1).select('first_name', 'last_name').then(... // operators: '=', '<', '>', '<=', '>=', 'like', 'not like', 'between', 'ilike' Knex('users').where('votes', '>', 100).exec(function(err, resp) { ... }); // chained with "andWhere" / "orWhere" Knex('users').where('votes', '>', 100) .andWhere('status', 'active') .orWhere('name', 'John') .then(function(resp) { ... }) // Even more where types (see list below): Knex('users').whereBetween('votes', [1, 100]).exec(... Knex('users').whereIn('id', [1, 2, 3]).then(... Knex('users').whereNotIn('id', [1, 2, 3]).then(... Knex('users').whereNull('updated_at').exec(...
Grouped Where Clauses:
// select * from users where name = 'John' or (votes > 100 and title <> 'Admin') Knex('users') .where('name', '=', 'John') .orWhere(function() { this.where('votes', '>', 100).andWhere('title', '<>', 'Admin'); }) .then(function() {...
Exists Statements:
Knex('users') .whereExists(function() { this.select(Knex.raw(1)) .from('orders') .whereRaw('orders.user_id = users.id'); }) .then(...
Most of the where clauses may also accept a function as the second argument, to generate a sub-select on the query:
// select author_id, content from comments where author_id in (select id from accounts where type = 'admin') Knex('comments').whereIn('author_id', function() { this.select('id').from('accounts').where('type', 'admin'); }).select('author_id', 'content').then(...
These different where clauses may be joined together in any number of ways to make valid SQL statements.
distinct.distinct()
Sets a distinct clause on the query.
// select distinct 'first_name' from customers Knex('customers') .distinct('first_name', 'last_name') .select()
join.join(table, first, operator, second, [type])
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. The last argument is optional and spefies the type of join.
Knex('users') .join('contacts', 'users.id', '=', 'contacts.user_id') .join('orders', 'users.id', '=', 'orders.user_id', 'outer') .select('users.id', 'contacts.phone', 'orders.price') .then(function() { ... });
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('users') .join('contacts', function() { this.on('users.id', '=', 'contacts.user_id').orOn(...); }) .exec(function(err, resp) { ... });
groupBy.groupBy(*names)
Adds a group by clause to the query.
orderBy.orderBy(column, [direction])
Adds an order by clause to the query.
having.having(column, operator, value)
Adds a having clause to the query.
Knex('users') .groupBy('count') .orderBy('name', 'desc') .having('count', '>', 100) .select()
offset.offset(value)
Adds an offset clause to the query.
limit.limit(value)
Adds a limit clause to the query.
Knex('users') .limit(10) .offset(30) .select()
union.union(query)
Creates a union query, taking a callback to build the union statement.
unionAll.unionAll(query)
Creates a union all query, with the same method signature as
the union method.
Knex('users').whereNull('last_name').union(function() { this.select('*').from('users').whereNull('first_name'); }).select().then(function() { ... });
insert.insert(data)
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] Knex('books').insert({title: 'Slaughterhouse Five'}) // Returns [2] in "mysql", "sqlite"; [2, 3] in "postgresql" Knex('books') .insert([{title: 'Great Gatsby'}, {title: 'Fahrenheit 451'}])
update.update(data)
Creates an update query, taking a hash of properties 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' }) .then(...
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()
count.count(column)
Performs a count on the specified column.
min.min(column)
Gets the minimum value for the specified column.
max.max(column)
Gets the maximum value for the specified column.
sum.sum(column)
Retrieve the sum of the values of a given column.
increment.increment(column, amount)
Increments a column value by the specified amount.
decrement.decrement(column, amount)
Decrements a column value by the specified amount.
truncate.truncate()
Truncates the current table.
debug.debug()
Turns on debugging for the current query chain.
then.then(onFulfilled, onRejected)
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.
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.
toString.toString()
Returns an array of query strings filled out with the
correct values based on bindings, etc. Useful for debugging.
Transactions are handled by passing a handler function into Knex.Transaction. The handler function accepts a single argument, the promise for committing or rolling back the transaction. This argument is then passed into any queries which are involved in the current transcaction, working by explicitly passing the .
Knex.Transaction(function(t) { Knex('books') .transacting(t) .insert({name: 'Old Books'}) .then(function(row) { return When.all(_.map([ {title: 'Canterbury Tales'}, {title: 'Moby Dick'}, {title: 'Hamlet'} ], function(info) { info.row_id = row.id; // Some validation could take place here. return Knex('book').transacting(t).insert(info); })); }) .then(t.commit, t.rollback); }).then(function() { console.log('3 new books saved.'); }, function() { console.log('Error saving the books.'); });
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.string('name'); table.timestamps(); }).then(function () { console.log('Users Table is Created!'); });
renameTableKnex.Schema.renameTable(from, to)
Renames a table from a current tableName to another.
dropTableKnex.Schema.dropTable(tableName)
Drops a table, specified by tableName.
hasTableKnex.Schema.hasTable(tableName)
Checks for a table's existence by tableName, with an error or failed promise if
the requested table does not exist.
Knex.Schema.hasTable('users').then(null, function() { return Knex.Schema.createTable('users', function(t) { t.increments('id').primary(); t.string('first_name', 100); t.string('last_name', 100); t.text('bio'); }); });
dropTableIfExistsKnex.Schema.dropTableIfExists(tableName)
Drops a table conditionally if the table exists, specified by tableName.
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'); }).then(function () { console.log('Users Table is Updated!'); });
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.
incrementstable.increments(name)
Adds an auto incrementing column. This will be used as the primary key for the column.
integertable.integer(name)
Adds an integer column.
texttable.text(name)
Adds a text column.
stringtable.string(name)
Adds a string column.
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)
Adds a timestamp column.
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).
enginetable.engine(val)
Sets the engine for the database, only available within a createTable call, and only
applicable to MySql.
The following three methods may be chained on the schema building methods, as modifiers to the column.
indexcolumn.index()
Specifies an integer as index. No-op if this is chained off of a non-integer field.
primarycolumn.primary()
Sets the field as the primary key for the table.
uniquecolumn.unique()
Sets the column as unique.
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.
nullablecolumn.nullable()
Allows a field to be nullable. No-op if chained off of a non-nullable field.
aftercolumn.after(field)
Sets the column to be inserted after another, only used in MySql alter tables.
Knex.Schema.createTable('accounts', function() { t.increments().primary(); t.string('email').unique(); });
Sometimes you may need to use a raw expression in a query. These expressions will be injected into the query as strings, so be careful not to create any SQL injection points! To create a raw expression, you may use the Knex.Raw function.
Knex('users') .select(Knex.Raw('count(*) as user_count, status')) .where('status', '<>', 1) .groupBy('status') .then(...
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. 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.Raw('select * from users where id = 1').then(function(resp) { ... });
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.
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', replacing with the path to your config file,
and the config file is valid, the test suite should run with npm test. If you're going to
add a test, you may want to follow similar patterns, used in the test suite,
setting $ export KNEX_DEV=1 to save the outputs data from the tests into the shared/output.js file.
Can I use Knex outside of Node.js
While there isn't a client adapter yet, it should be possible to run
it could be adapted to work with other javascript environments supporting a sqlite3
database, by providing a custom Knex adapter.
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.