Skip to content
Open
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
17 changes: 17 additions & 0 deletions index.d.ts
Original file line number Diff line number Diff line change
Expand Up @@ -44,6 +44,23 @@ export class SQLStatement {
*/
append(statement: SQLStatement | string | number): this

/**
* Unnests any nested SQLStatements so that their values are merged into this statement
*
* ```ts
* const book = 'harry potter'
* const author = 'J. K. Rowling'
* const query = SQL`SELECT author FROM books WHERE genre IN (${SQL`SELECT category FROM books WHERE name = ${book}`}) AND author = ${author}`
*
* query.unnest()
*
* query.sql // => 'SELECT author FROM books WHERE genre IN (SELECT category FROM books WHERE name = ?) AND author = ?'
* query.text // => 'SELECT author FROM books WHERE genre IN (SELECT category FROM books WHERE name = $1) AND author = $2'
* query.values // => ['harry potter', 'J. K. Rowling']
* ```
*/
unnest(recursive?: boolean): this

/**
* Sets the name property of this statement for prepared statements in postgres
*
Expand Down
27 changes: 27 additions & 0 deletions index.js
Original file line number Diff line number Diff line change
Expand Up @@ -36,6 +36,33 @@ class SQLStatement {
return this
}

/**
* Unnest any nested SQLStatements within this SQLStatement
* @param {boolean} [recursive=true] Whether to unnest recursively
* @returns {this}
*/
unnest(recursive = true) {
const strings = []
const values = []
strings.push(this.strings[0])
for (let i = 0; i < this.values.length; i++) {
const value = this.values[i]
if (value instanceof SQLStatement) {
const nest = recursive ? value.unnest(recursive) : value
strings[strings.length - 1] += nest.strings[0]
strings.push(...nest.strings.slice(1))
values.push(...nest.values)
strings[strings.length - 1] += this.strings[i + 1]
} else {
values.push(value)
strings.push(this.strings[i + 1])
}
}
this.strings = strings
this.values = values
return this
}

/**
* Use a prepared statement with Sequelize.
* Makes `query` return a query with `$n` syntax instead of `?` and switches the `values` key name to `bind`
Expand Down
70 changes: 70 additions & 0 deletions test/unit.js
Original file line number Diff line number Diff line change
Expand Up @@ -20,6 +20,76 @@ describe('SQL', () => {
assert.deepEqual(query.values, [value])
})

it('should work with a nested query', () => {
const value1 = 1234
const value2 = 5678
const value3 = 9012
const query1 = SQL`SELECT column2 FROM other_table WHERE column = ${value2} ORDER BY column2`
const query2 = SQL`SELECT * FROM table WHERE column1 = ${value1} AND column2 IN (${query1}) AND column3 = ${value3}`
query2.unnest()
assert.equal(
query2.sql,
'SELECT * FROM table WHERE column1 = ? AND column2 IN (SELECT column2 FROM other_table WHERE column = ? ORDER BY column2) AND column3 = ?'
)
assert.equal(
query2.query,
'SELECT * FROM table WHERE column1 = ? AND column2 IN (SELECT column2 FROM other_table WHERE column = ? ORDER BY column2) AND column3 = ?'
)
assert.equal(
query2.text,
'SELECT * FROM table WHERE column1 = $1 AND column2 IN (SELECT column2 FROM other_table WHERE column = $2 ORDER BY column2) AND column3 = $3'
)
assert.deepEqual(query2.values, [value1, value2, value3])
})

it('should work with a deeply nested query', () => {
const value1 = 1234
const value2 = 5678
const value3 = 9012
const value4 = 3456
const query1 = SQL`SELECT column2 FROM other_table1 WHERE column = ${value2} ORDER BY column2`
const query2 = SQL`SELECT column2 FROM other_table2 WHERE column IN (${query1}) AND column3 = ${value3} ORDER BY column3`
const query3 = SQL`SELECT * FROM table WHERE column1 = ${value1} AND column2 IN (${query2}) AND column4 = ${value4}`
query3.unnest()
assert.equal(
query3.sql,
'SELECT * FROM table WHERE column1 = ? AND column2 IN (SELECT column2 FROM other_table2 WHERE column IN (SELECT column2 FROM other_table1 WHERE column = ? ORDER BY column2) AND column3 = ? ORDER BY column3) AND column4 = ?'
)
assert.equal(
query3.query,
'SELECT * FROM table WHERE column1 = ? AND column2 IN (SELECT column2 FROM other_table2 WHERE column IN (SELECT column2 FROM other_table1 WHERE column = ? ORDER BY column2) AND column3 = ? ORDER BY column3) AND column4 = ?'
)
assert.equal(
query3.text,
'SELECT * FROM table WHERE column1 = $1 AND column2 IN (SELECT column2 FROM other_table2 WHERE column IN (SELECT column2 FROM other_table1 WHERE column = $2 ORDER BY column2) AND column3 = $3 ORDER BY column3) AND column4 = $4'
)
assert.deepEqual(query3.values, [value1, value2, value3, value4])
})

it('should work with a deeply nested query and partial unnest', () => {
const value1 = 1234
const value2 = 5678
const value3 = 9012
const value4 = 3456
const query1 = SQL`SELECT column2 FROM other_table1 WHERE column = ${value2} ORDER BY column2`
const query2 = SQL`SELECT column2 FROM other_table2 WHERE column IN (${query1}) AND column3 = ${value3} ORDER BY column3`
const query3 = SQL`SELECT * FROM table WHERE column1 = ${value1} AND column2 IN (${query2}) AND column4 = ${value4}`
query3.unnest(false)
assert.equal(
query3.sql,
'SELECT * FROM table WHERE column1 = ? AND column2 IN (SELECT column2 FROM other_table2 WHERE column IN (?) AND column3 = ? ORDER BY column3) AND column4 = ?'
)
assert.equal(
query3.query,
'SELECT * FROM table WHERE column1 = ? AND column2 IN (SELECT column2 FROM other_table2 WHERE column IN (?) AND column3 = ? ORDER BY column3) AND column4 = ?'
)
assert.equal(
query3.text,
'SELECT * FROM table WHERE column1 = $1 AND column2 IN (SELECT column2 FROM other_table2 WHERE column IN ($2) AND column3 = $3 ORDER BY column3) AND column4 = $4'
)
assert.deepEqual(query3.values, [value1, query1, value3, value4])
})

it('should work with falsy values', () => {
const value1 = false
const value2 = null
Expand Down