Code Monkey home page Code Monkey logo

sql-bricks-postgres's Introduction

PostgreSQL dialect for SQLBricks

This is a lightweight, schemaless library helping you to generate statements for PostgreSQL. It is based on sql-bricks and adds PostgreSQL specific things into it.

You might also want to take a look at pg-bricks, which adds query execution, connections and transaction handling on top of this library.

Usage

// in node:
var sql = require('sql-bricks-postgres');
// in the browser:
var sql = PostgresBricks;

sql.select().from('user').where({name: 'Fred'}).toParams();
// {text: 'SELECT * FROM "user" WHERE name = $1', values: ['Fred']}

sql.select().from('user').where({name: 'Fred'}).toString();
// SELECT * FROM "user" WHERE name = 'Fred'

// NOTE: never use .toString() to execute a query,
//       leave values for db library to quote

You can read about basic flavor of how this thing works in sql-bricks documentation. Here go PostgreSQL specifics.

LIMIT and OFFSET

sql.select().from('user').limit(10).offset(20).toString()
// SELECT * FROM "user" LIMIT 10 OFFSET 20

RETURNING

sql.update('user', {name: 'John'}).where({id: 1}).returning('*')
// UPDATE "user" SET name = 'John' WHERE id = 1 RETURNING *

sql.delete('job').where({finished: true}).returning('id')
// DELETE FROM job WHERE finished = TRUE RETURNING id

UPDATE ... FROM

sql.update('setting', {value: sql('V.value')})
   .from('val as V').where({name: sql('V.name')}).toString()
// UPDATE setting SET value = V.value
//   FROM val as V WHERE name = V.name

DELETE ... USING

sql.delete('user').using('address')
   .where('user.addr_fk', sql('address.pk'))
// DELETE FROM user USING address WHERE user.addr_fk = address.pk

ON CONFLICT ... DO NOTHING / DO UPDATE ...

The most popular use case is probably UPSERT:

sql.insert('user', {name: 'Alex', age: 34})
   .onConflict('name').doUpdate('age')
// INSERT INTO "user" (name) VALUES ('Alex', 34)
//     ON CONFLICT (name) DO UPDATE SET age = EXCLUDED.age

// sql-bricks-postgres will update all fields if none are specified
sql.insert('user', {name: 'Alex', age: 34})
   .onConflict('name').doUpdate()
// INSERT INTO "user" (name) VALUES ('Alex', 34)
//   ON CONFLICT (name)
//   DO UPDATE SET name = EXCLUDED.name, age = EXCLUDED.age

// manipulate the data in the `DO UPDATE`:
sql.insert('user', {name: 'Alex', age: 34})
    .onConflict('name').doUpdate()
    .set(sql('name = coalesce(EXCLUDED.name, $1), age = $2 + 10', t1, t2))
// INSERT INTO "user" (name) VALUES ('Alex', 34)
//   ON CONFLICT (name)
//   DO UPDATE SET name = coalesce(EXCLUDED.name, $3), age = $4 + 10

Other clauses such as DO NOTHING, ON CONSTRAINT and WHERE are also supported:

sql.insert('user', ...).onConflict('name').where({is_active: true})
   .doNothing()
// INSERT INTO "user" ... VALUES ...
//     ON CONFLICT (name) WHERE is_active = true DO NOTHING

sql.insert('user', ...).onConflict().onConstraint('name_idx')
    .doUpdate().where(sql('is_active'))
// INSERT INTO "user" ... VALUES ...
//     ON CONFLICT ON CONSTRAINT name_idx
//     DO UPDATE SET ... WHERE is_active"

FROM VALUES

VALUES statement is a handy way to provide data with a query. It is most known in a context of INSERT, but could be used for other things like altering selects and doing mass updates:

var data = [{name: 'a', value: 1}, {name: 'b', value: 2}];
sql.select().from(sql.values(data)).toString();
// SELECT * FROM (VALUES ('a', 1), ('b', 2))

sql.update('setting s', {value: sql('v.value')})
   .from(sql.values({name: 'a', value: 1}).as('v').columns())
   .where('s.name', sql('v.name')}).toString()
// UPDATE setting s SET value = v.value
//   FROM (VALUES ('a', 1)) v (name, value) WHERE s.name = v.name

Sometimes you need types on values columns for query to work. You can use .types() method to provide them:

var data = {i: 1, f: 1.5, b: true, s: 'hi'};
insert('domain', _.keys(data))
    .select().from(sql.values(data).as('v').columns().types())
    .where(sql.not(sql.exists(
        select('1').from('domain d')
        .where({'d.job_id': sql('v.job_id'), 'd.domain': sql('v.domain')}))))
// INSERT INTO domain (i, f, b, s)
// SELECT * FROM (VALUES ($5::int, $6::float, $7::bool, $8)) v (i, f, b, s)
// WHERE NOT EXISTS
//    (SELECT 1 FROM domain d WHERE d.job_id = v.job_id AND d.domain = v.domain)

When type can't detected by value, e.g. you have null, no cast will be added. However, you can specify types explicitly:

sql.values({field: null}).types({field: 'int'}).toString()
// VALUES (null::int)

ILIKE

ILIKE is a case insensitive LIKE statement

sql.select("text").from("example").where(sql.ilike("text", "%EASY%"))
// SELECT text FROM example WHERE text ILIKE '%EASY%'

PostgreSQL Type Compatability

Supports node-postgres toPostgres() conventions to format Javascript appropriately for PostgreSQL. See postgres-interval for an example of this pattern in action. (index.js#L14-L22)

Even Harder Things

PostgreSQL has lots of functions and operators so it's inpractical to support everything, instead simple fallback is offered:

select().from('time_limit')
        .where(sql('tsrange(start, end) @> tsrange($1, $2)', t1, t2))
// SELECT * FROM time_limit
// WHERE tsrange(start, end) @> tsrange($1, $2)

Note $<number> placeholders.

sql-bricks-postgres's People

Stargazers

 avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar

Watchers

 avatar  avatar  avatar  avatar  avatar

sql-bricks-postgres's Issues

Range operators and functions

I'd like to use some range queries such as

SELECT *
FROM   time_limits
WHERE  name = 'lucy`
AND    tsrange(start_date_time, end_date_time, '[]')
    @> tsrange('2010-08-08 00:00', '2010-08-08 00:05', '[]')

As per this bit of the postgres manual http://www.postgresql.org/docs/9.2/static/functions-range.html

I can't work out a way to do this with postgres-bricks (I might be aiming at the wrong place here and maybe this issue should be in the sql-bricks module but I think it's postgres specific right now).

Is there a simple way to hack this in without an update to sql-brick-postgres ?

v0.6.0 Cloned statement doesn't have postgres methods

Hi,

After upgrading from 0.5.0 into 0.6.0 cloned statements stops working.

Steps to reproduce:

const query = sql.select().from('user');
query.limit(10); // <--- this is working
const query2 = query.clone();
query2.limit(10); // <--- this not working in 0.6.0 (limit is not a function)

Probably upgrading sqlBricks to v3 makes this issue.

jsonb containment operators not supported, how to implement properly?

I am trying to use sql-bricks-postgres (through pg-bricks) to create queries containing where clauses with jsonb containment operators. I noticed these are not supported in sql-bricks-postgres.

Diving into this it turns out sql-bricks itself is written in such a way that the base prototypes for these infix operators are not exposed. To me the only way to add new operators seems to be to create an existing operator (such as eq or equal) and then changing the operator property:

var sql = require('sql-bricks-postgres');
sql.jsonb_contains = function (col, val) {
  var lt = sql.lt(col, val);
  lt.op = "@>";
  return lt;
};

sql.select().where(sql.jsonb_contains('field', { key: 'value' }))

While this "hack" returns correct SQL queries, do you know whether there are more appropriate methods for adding operators?

Update `noWait` for postgres

With sql-bricks, noWait builds SQL such as:

select('addr_id').from('person').forUpdate().of('addr_id').noWait();
// SELECT addr_id FROM person FOR UPDATE OF addr_id NO WAIT

For postgres though, NO WAIT should be NOWAIT. Is it possible to make this change in this module?

Composite "WHERE IN" Support

Support for composite "IN" conditions where two or more fields are specified along with a multidimensional array or array of objects.

e.g.

sql.in("(col1,col2)", [[1,2],[3,4]]);

Currently invalid example result:
SELECT * FROM beacons WHERE (major, minor) IN ('64404,20884','47805,16497')

Expected example result:
SELECT * FROM beacons WHERE (major, minor) IN (('64404','20884'),('47805','16497'))

Current work-around (after validating the multidimensional array):
sql.in("(major, minor)", sql(myMultidimensionalArray.map(function(pair, index) {return '(' + pair[0] + ',' + pair[1] + ')';}).join(',')))

See also:
http://stackoverflow.com/questions/6672665/doing-a-where-in-on-multiple-columns-in-postgresql

Originated on Twitter: https://twitter.com/nickschwab/status/629024436532944896
Moved to sql-bricks-postgres after deliberation in sql-bricks: CSNW/sql-bricks#72 (comment)

"invalid message format" error when string to write contains a NUL character

When I send a string with a \0 in it, I get an "invalid message format" error.

var sql = require('sql-bricks-postgres');

// pool is the "pool" object provided by module pg 6.1.0
pool.connect(function(error, client, done) {
  if (error) return console.error(error.stack);

  client.query(sql.insertInto('test', 's').values('test\0').toString(), function(error, result) {
    if (error) return console.error(error.stack);
  });
});

I get:

error: invalid message format
at Connection.parseE (/Users/raphaelchampeimont/nodejs-doctrine/node_modules/pg/lib/connection.js:554:11)
at Connection.parseMessage (/Users/raphaelchampeimont/nodejs-doctrine/node_modules/pg/lib/connection.js:381:17)
at TLSSocket. (/Users/raphaelchampeimont/nodejs-doctrine/node_modules/pg/lib/connection.js:117:22)
at emitOne (events.js:77:13)
at TLSSocket.emit (events.js:169:7)
at readableAddChunk (_stream_readable.js:153:18)
at TLSSocket.Readable.push (_stream_readable.js:111:10)
at TLSWrap.onread (net.js:536:20)

I am using [email protected]

doUpdate argument is an array not string

In the document there is an example as follow:

.onConflict('name').doUpdate('age')

but actually it should be:

.onConflict('name').doUpdate(['age'])

do I miss a thing?

Binary is a reserved word in Postgres and so maybe others

In contrast to the reserved words in sql-bricks https://github.com/CSNW/sql-bricks/blob/master/sql-bricks.js#L1001, I think sql-bricks-postgres needs a variant to that list.

For example, this:

const update = require('sql-bricks-postgres').update
const { text, values } = update('data.file', {binary: <Buffer 49 44 ... >}).where('id', 1).toParams()

// text --> UPDATE data.file SET binary = $1 WHERE id = $2
// values: [  <Buffer 49 44 ... >, 1 ]
await pg_client.query(text, values)

Fails with this error:

syntax error at or near "binary"

Or should I direct this issue at sql-bricks?

array update/inserts malformed

I'm not sure if this is an issue in sql-bricks or an issue in sql-bricks-postgres, so I'm creating issues in both projects.

When I try to insert (or update) into an array column of type uuid[], then value is malformed. There should be quotes around it, but there are not.

sql-bricks generates this:

 INSERT INTO my_table (empty_array, array_with_something) VALUES ({}, {'aee828d5-6615-4fbd-bc58-41ccd39470ae'})

but should generate

 INSERT INTO my_table (empty_array, array_with_something) VALUES ('{}','{\'aee828d5-6615-4fbd-bc58-41ccd39470ae\'}')

I am able to get the query to work with the following regex, though this would not work in all cases:

    sql = sql.replace(/(\{)([^\}]*)(\})/g, function(ignore1, ignore2, content) {
        return '\'{' + content.replace(/\'/g, '"') + '}\'';
    });

Recommend Projects

  • React photo React

    A declarative, efficient, and flexible JavaScript library for building user interfaces.

  • Vue.js photo Vue.js

    ๐Ÿ–– Vue.js is a progressive, incrementally-adoptable JavaScript framework for building UI on the web.

  • Typescript photo Typescript

    TypeScript is a superset of JavaScript that compiles to clean JavaScript output.

  • TensorFlow photo TensorFlow

    An Open Source Machine Learning Framework for Everyone

  • Django photo Django

    The Web framework for perfectionists with deadlines.

  • D3 photo D3

    Bring data to life with SVG, Canvas and HTML. ๐Ÿ“Š๐Ÿ“ˆ๐ŸŽ‰

Recommend Topics

  • javascript

    JavaScript (JS) is a lightweight interpreted programming language with first-class functions.

  • web

    Some thing interesting about web. New door for the world.

  • server

    A server is a program made to process requests and deliver data to clients.

  • Machine learning

    Machine learning is a way of modeling and interpreting data that allows a piece of software to respond intelligently.

  • Game

    Some thing interesting about game, make everyone happy.

Recommend Org

  • Facebook photo Facebook

    We are working to build community through open source technology. NB: members must have two-factor auth.

  • Microsoft photo Microsoft

    Open source projects and samples from Microsoft.

  • Google photo Google

    Google โค๏ธ Open Source for everyone.

  • D3 photo D3

    Data-Driven Documents codes.