New issue
Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.
By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.
Already on GitHub? Sign in to your account
feat(query-generator): Generate INSERTs using bind parameters #9431
feat(query-generator): Generate INSERTs using bind parameters #9431
Conversation
lib/data-types.js
Outdated
@@ -725,6 +739,9 @@ GEOGRAPHY.prototype.escape = false; | |||
GEOGRAPHY.prototype._stringify = function _stringify(value, options) { | |||
return 'GeomFromText(' + options.escape(Wkt.convert(value)) + ')'; | |||
}; | |||
GEOMETRY.prototype.bindParam = function bindParam(value, options) { |
There was a problem hiding this comment.
Choose a reason for hiding this comment
The reason will be displayed to describe this comment to others. Learn more.
_bindParam
to match _stringify
etc stuff
@@ -989,11 +989,18 @@ class QueryGenerator { | |||
return SqlString.escape(value, this.options.timezone, this.dialect); | |||
} | |||
|
|||
bindParam(bind) { |
There was a problem hiding this comment.
Choose a reason for hiding this comment
The reason will be displayed to describe this comment to others. Learn more.
👍
test/integration/data-types.test.js
Outdated
@@ -56,14 +56,18 @@ describe(Support.getTestDialectTeaser('DataTypes'), () => { | |||
}); | |||
}); | |||
|
|||
const testSuccess = function(Type, value) { | |||
const testSuccess = function(Type, value, useBindParam) { |
There was a problem hiding this comment.
Choose a reason for hiding this comment
The reason will be displayed to describe this comment to others. Learn more.
Third argument should be options with arbitrary configuration possibilities { useBindParam }
@sushantdhiman Hit a bit of a snag doing upserts with Postgres. The current CREATE OR REPLACE FUNCTION pg_temp.sequelize_upsert(OUT created boolean,OUT primary_key text) AS $func$
BEGIN
INSERT INTO "users" ("id","username","zab","createdAt","updatedAt") VALUES (1,"john","foo","1970-01-01 00:00:00.000 +00:00","1970-01-01 00:00:00.000 +00:00"); created := true;
EXCEPTION WHEN unique_violation THEN
UPDATE "users" SET "id"=42,"username"='john',"updatedAt"='1970-01-01 00:00:00.000 +00:00' WHERE ("id" = 42); created := false;
END;
$func$ LANGUAGE plpgsql;
SELECT * FROM pg_temp.sequelize_upsert(); That's fine when not using bind parameters/prepared statements, but when I generate something along the lines of: CREATE OR REPLACE FUNCTION pg_temp.sequelize_upsert(arg1 <argtype>,arg2 <argtype>,arg3 <argtype>,arg4 <argtype>,arg5 <argtype>,OUT created boolean,OUT primary_key text) AS $func$
BEGIN
INSERT INTO "users" ("id","username","zab","createdAt","updatedAt") VALUES (arg1,arg2,arg3,arg4,arg5); created := true;
EXCEPTION WHEN unique_violation THEN
UPDATE "users" SET "id"=42,"username"='john',"updatedAt"='1970-01-01 00:00:00.000 +00:00' WHERE ("id" = 42); created := false;
END;
$func$ LANGUAGE plpgsql;
SELECT * FROM pg_temp.sequelize_upsert($1,$2,$3,$4,$5); I get an error back from Postgres of [
{
"query": "CREATE OR REPLACE FUNCTION pg_temp.sequelize_upsert(arg1 <argtype>,arg2 <argtype>,arg3 <argtype>,arg4 <argtype>,arg5 <argtype>,OUT created boolean,OUT primary_key text) AS $$func$$ BEGIN INSERT INTO \"users\" (\"id\",\"username\",\"zab\",\"createdAt\",\"updatedAt\") VALUES (arg1,arg2,arg3,arg4,arg5); created := true; EXCEPTION WHEN unique_violation THEN UPDATE \"users\" SET \"id\"=42,\"username\"='john',\"updatedAt\"='1970-01-01 00:00:00.000 +00:00' WHERE (\"id\" = 42); created := false; END; $$func$$ LANGUAGE plpgsql;",
"bind": []
},
{
"query": "SELECT * FROM pg_temp.sequelize_upsert($1,$2,$3,$4,$5);",
"bind": [42, "john", "foo", "1970-01-01 00:00:00.000 +00:00", "1970-01-01 00:00:00.000 +00:00"]
}
] And have something further up treat an array of query elements as something that must be run as a sequence of statements that must be run one after each other. Does that seem reasonable to you? |
You are right, we can't use parameterized query with multiple statements. It seems we need to execute two queries with correct order, also keeping other
Yeah I agree, we need to return multiple statements with their parameters. In old approach we used to send one single query which will create / replace function and execute it at server level, but now we need to wrap Another potential solution is to support So overall, we need to do this
|
The tests are now passing on everything apart from Postgres which is becoming increasingly complex. There's still some fixes needed to support RANGE correctly with bind params, and I've also spotted the Postgres specific code that is returned by the abstract insertQuery which needs the same treatment. This PR is starting to get quite large too. So that I can split this work up better, would it be acceptable to have an option to turn off bindParams? This would let me:
I can then postpone having to deal with returning multiple queries and the further complexity that entails. There's also a good opportunity at that point to remove the duplicate code in insertQuery so that it calls fn/exceptionFn in postgres/query-generator.js |
Sounds good to me :) |
Sounds good if we keep it as a private option, Use it internally so we can keep converting old queries to parameter based queries and then remove it eventually |
d3bb785
to
09fe634
Compare
@janmeier @sushantdhiman Any chance either of you could try running the tests yourselves? I can't reproduce the failures in Travis 😕 |
Works locally for me as well.... |
You need to rebase on top of latest master (specifically this commit b66f9dd has some tests that are now failing) I was tipped up by the fact that my local tests said 1764 passing, while travis was 1764 passing, 4 failing so I figured my local copy was missing something |
@janmeier Ooops! I'll try and sort it over lunch. |
0fb148e
to
8614879
Compare
Tests are all green 🎉 |
expectation: { | ||
query: 'INSERT INTO `myTable` (`name`,`value`) VALUES ($1,$2);', | ||
// TODO: Check | ||
bind: ['foo', true] |
There was a problem hiding this comment.
Choose a reason for hiding this comment
The reason will be displayed to describe this comment to others. Learn more.
Should be fine (I'm pretty sure sqlite takes whatever you throw at it)
expectation: "INSERT INTO `myTable` (`name`,`value`) VALUES ('bar',NULL);" | ||
expectation: { | ||
query: 'INSERT INTO `myTable` (`name`,`value`) VALUES ($1,$2);', | ||
// TODO: Check |
There was a problem hiding this comment.
Choose a reason for hiding this comment
The reason will be displayed to describe this comment to others. Learn more.
Hmm, not sure - There is another issue about ignoring undefined completely, but it should be fine for now
8614879
to
bf9eb5e
Compare
There was a problem hiding this comment.
Choose a reason for hiding this comment
The reason will be displayed to describe this comment to others. Learn more.
Looks good, some small changes
query = _.template(query, this._templateSettings)(replacements); | ||
// Used by Postgres upsertQuery and calls to here with options.exception set to true | ||
if (options.bindParam === false) { | ||
return query; |
There was a problem hiding this comment.
Choose a reason for hiding this comment
The reason will be displayed to describe this comment to others. Learn more.
return an object in both cases, so all calls can just use .query
. In case options.bindParam: false
return no bind parameters.
There was a problem hiding this comment.
Choose a reason for hiding this comment
The reason will be displayed to describe this comment to others. Learn more.
Done
@@ -169,7 +171,14 @@ class QueryGenerator { | |||
} | |||
} | |||
|
|||
if (_.get(this, ['sequelize', 'options', 'dialectOptions', 'prependSearchPath']) || options.searchPath) { |
There was a problem hiding this comment.
Choose a reason for hiding this comment
The reason will be displayed to describe this comment to others. Learn more.
Use full path sequelize.options.dialectOptions.prependSearchPath
in _.get
There was a problem hiding this comment.
Choose a reason for hiding this comment
The reason will be displayed to describe this comment to others. Learn more.
I can change it, but it's more efficient in Lodash to use the array path form. If you use the string path form (e.g. _.get(this, 'sequelize.options.dialectOptions.prependSearchPath')
) Lodash first converts it back to the array path form which currently entails a bunch of regex operations to parse the path. For a single call like this it probably doesn't matter, but do it many times and there's a big difference in performance.
There was a problem hiding this comment.
Choose a reason for hiding this comment
The reason will be displayed to describe this comment to others. Learn more.
@gazoakley No need to change it then :)
return this.User.create({ | ||
dates: [] | ||
}, { | ||
logging(sql) { | ||
expect(sql.indexOf('TIMESTAMP WITH TIME ZONE')).to.be.greaterThan(0); | ||
expect(sql).not.to.contain('TIMESTAMP WITH TIME ZONE'); | ||
expect(sql).not.to.contain('DATETIME'); |
There was a problem hiding this comment.
Choose a reason for hiding this comment
The reason will be displayed to describe this comment to others. Learn more.
assert presence of bind param?
There was a problem hiding this comment.
Choose a reason for hiding this comment
The reason will be displayed to describe this comment to others. Learn more.
I think all the tests asserting on SQL can be covered with unit tests instead
bf9eb5e
to
8fc477a
Compare
Now we just need to make |
@gazoakley Hi there! Is there any progress on supporting bind params for select, update and delete? Thanks a lot! |
Pull Request check-list
Please make sure to review and check all of these items:
npm run test
ornpm run test-DIALECT
pass with this change (including linting)?Description of change
This is a new spin of #9371 where I've removed the
bindParams
option and updated all the INSERT unit tests to match the new syntax. It's thrown up a few issues:GEOMETRY
) cause issues since drivers can't identify them before sending them as bind parameters. They need to be sent using a correct CAST and providing the bind parameter in string form e.g.GeomFromText($1)
with a valid bind param