Thread: Alias hstore's ? to ~ so that it works with JDBC
hi, As reported in BUG #7715 [1], hstore's use of ? as an operator conflicts with JDBC's bind variables. I think we could just alias ? to ~ and tell JDBC users to use that instead. [2] Best, Seamus [1] http://www.postgresql.org/message-id/E1TeIju-0003qb-WD@wrigleys.postgresql.org [2] https://gist.github.com/seamusabshere/4715959/revisions -- Seamus Abshere seamus@abshere.net https://github.com/seamusabshere
On Tue, Feb 5, 2013 at 11:29 AM, Seamus Abshere <seamus@abshere.net> wrote: > hi, > > As reported in BUG #7715 [1], hstore's use of ? as an operator conflicts > with JDBC's bind variables. > > I think we could just alias ? to ~ and tell JDBC users to use that instead. > [2] This is not a bug with postgres, but with java/JDBC. There are many operators that use '?' besides hstore and JDBC should allow for escaping out of its statement interpretation. merlin
On Wed, Feb 6, 2013 at 11:20 AM, Seamus Abshere <seamus@abshere.net> wrote: > merlin, > > Yes, you're correct, my phrasing was bad: all I meant was that it was a > conflict, not a bug in Postgres or hstore. > > I personally don't know of any way around the conflict except changing JDBC > or hstore, and I don't think JDBC is gonna change. > > Deciding not to accommodate JDBC on the Postgres side, though, is going to > prevent hstore from being used properly with Java or any JVM-based language > like JRuby. > > Please let me know if my assumptions are wrong. This problem is not unique to ? character. Hibernate for example reserves the use of : character for name parameter insertion with similarly ridiculous results. Basically every language I know of except for the java stack seems to understand that when embedding constructs into a foreign language there must be some type of escaping mechanism (note they may in fact allow this in some level: via googling it isn't clear). The point is that Postgres should not introduce language constraints because of broken driver technology. To move forward in your particular case, consider: *) switching to 'hstore defined()' function: *) hacking pg_operator (carefully look up and change oprname for the specific hstore operator) merlin
On 02/06/2013 12:34 PM, Merlin Moncure wrote: > > The point is that Postgres should not introduce language constraints > because of broken driver technology. +1 > To move forward in your > particular case, consider: > *) switching to 'hstore defined()' function: good solution - but just use the existing "exist()" function. > *) hacking pg_operator (carefully look up and change oprname for the > specific hstore operator) bad solution. Why not just provide an additional operator? CREATE OPERATOR ~ ( LEFTARG = hstore, RIGHTARG = text, PROCEDURE = exist, RESTRICT = contsel, JOIN = contjoinsel ); cheers andrew
On Wed, Feb 6, 2013 at 12:00 PM, Andrew Dunstan <andrew@dunslane.net> wrote: > > On 02/06/2013 12:34 PM, Merlin Moncure wrote: >> >> >> The point is that Postgres should not introduce language constraints >> because of broken driver technology. > > > +1 > > >> To move forward in your >> particular case, consider: >> *) switching to 'hstore defined()' function: > > > good solution - but just use the existing "exist()" function. > > >> *) hacking pg_operator (carefully look up and change oprname for the >> specific hstore operator) > > > bad solution. Why not just provide an additional operator? > > CREATE OPERATOR ~ ( > LEFTARG = hstore, > RIGHTARG = text, > PROCEDURE = exist, > RESTRICT = contsel, > JOIN = contjoinsel > ); yeah, this is much less hacky way to go. merlin
tl;dr Scala/JRuby/Clojure (any JVM-based language) + Postgres + hstore = awesome... why not just add a few lines to hstore--1.2.sql and make sure that all operators are available and indexable? hi Andrew, hi merlin, > use the existing "exist()" function EXIST() can't use hstore's GiST or GIN indexes. > Why not just provide an additional operator? > > CREATE OPERATOR ~ ( > LEFTARG = hstore, > RIGHTARG = text, > PROCEDURE = exist, > RESTRICT = contsel, > JOIN = contjoinsel > ); Since the goal is to get ? working on JDBC with indexes, I think you also have to do CREATE OPERATOR CLASS [1] Best, Seamus [1] See my revision of hstore--1.1.sql at https://gist.github.com/seamusabshere/4715959/revisions -- Seamus Abshere seamus@abshere.net https://github.com/seamusabshere
On Wed, Feb 6, 2013 at 11:42 PM, Merlin Moncure <mmoncure@gmail.com> wrote:
------
With best regards,
Alexander Korotkov.
>> *) hacking pg_operator (carefully look up and change oprname for theyeah, this is much less hacky way to go.
>> specific hstore operator)
>
>
> bad solution. Why not just provide an additional operator?
>
> CREATE OPERATOR ~ (
> LEFTARG = hstore,
> RIGHTARG = text,
> PROCEDURE = exist,
> RESTRICT = contsel,
> JOIN = contjoinsel
> );
But, you need to add new operator to opclasses in order to use GiST and GIN indexes.
Another solution is to create SQL functionw which calls operator:
CREATE FUNCTION exists_inline (hstore, text) RETURNS bool AS $$ SELECT $1 ? $2; $$ LANGUAGE sql;
It will inline and use indexes.
With best regards,
Alexander Korotkov.
merlin, Yes, you're correct, my phrasing was bad: all I meant was that it was a conflict, not a bug in Postgres or hstore. I personally don't know of any way around the conflict except changing JDBC or hstore, and I don't think JDBC is gonna change. Deciding not to accommodate JDBC on the Postgres side, though, is going to prevent hstore from being used properly with Java or any JVM-based language like JRuby. Please let me know if my assumptions are wrong. Best, Seamus On 2/6/13 10:58 AM, Merlin Moncure wrote: > On Tue, Feb 5, 2013 at 11:29 AM, Seamus Abshere <seamus@abshere.net> wrote: >> As reported in BUG #7715 [1], hstore's use of ? as an operator conflicts >> with JDBC's bind variables. >> >> I think we could just alias ? to ~ and tell JDBC users to use that instead. > > This is not a bug with postgres, but with java/JDBC. There are many > operators that use '?' besides hstore and JDBC should allow for > escaping out of its statement interpretation. > > merlin >
merlin, I appreciate your perspective and wish that JDBC didn't present this problem. Still, with the rapidly growing adoption of both Postgres and JVM-based languages (thanks Heroku!) - plus the special power of hstore - I think it would be a shame if such a small accommodation could not be made. Other hackers, What is your take? Best, Seamus PS. Switching to the EXIST() or DEFINED() functions is not, in my opinion, a solution because they can't use hstore's GiST or GIN indexes. On 2/6/13 11:34 AM, Merlin Moncure wrote: > The point is that Postgres should not introduce language constraints > because of broken driver technology. To move forward in your > particular case, consider: > *) switching to 'hstore defined()' function: > *) hacking pg_operator (carefully look up and change oprname for the > specific hstore operator)
On Wed, 6 Feb 2013, Seamus Abshere wrote: > I personally don't know of any way around the conflict except changing > JDBC or hstore, and I don't think JDBC is gonna change. > I think changing JDBC is the way to go. Currently JDBC supports escape sequences for cross database portability and it seems reasonable to support an escape sequence that allowed passing ? to the backend instead of interpreting it as a parameter. This will be more complicated than you might hope because the escape processing currently happens prior to bind parameter detection so I'm not sure what a good patch would really look like, but given the feedback provided here, it's worth investigating. Kris Jurka
On Fri, Feb 8, 2013 at 11:43 AM, Kris Jurka <books@ejurka.com> wrote:
Dave Cramer
dave.cramer(at)credativ(dot)ca
I think changing JDBC is the way to go. Currently JDBC supports escape
On Wed, 6 Feb 2013, Seamus Abshere wrote:
> I personally don't know of any way around the conflict except changing
> JDBC or hstore, and I don't think JDBC is gonna change.
>
sequences for cross database portability and it seems reasonable to
support an escape sequence that allowed passing ? to the backend instead
of interpreting it as a parameter. This will be more complicated than you
might hope because the escape processing currently happens prior to bind
parameter detection so I'm not sure what a good patch would really look
like, but given the feedback provided here, it's worth investigating.
Kris Jurka
Would this be an postgresql specific escape sequence ? I don't think the spec allows for this does it ?
dave.cramer(at)credativ(dot)ca
On Fri, 8 Feb 2013, Dave Cramer wrote: > Would this be an postgresql specific escape sequence ? I don't think the > spec allows for this does it ? > Yes, this would be a postgresql jdbc driver specific escape. The spec doesn't have a concept of private escape sequences, but that doesn't seem like the end of the world. Clearly the user here is writing postgresql specific code to use hstore operators, so there's not a portability loss here. Kris Jurka
On 02/08/2013 12:41 PM, Kris Jurka wrote: > > On Fri, 8 Feb 2013, Dave Cramer wrote: > >> Would this be an postgresql specific escape sequence ? I don't think the >> spec allows for this does it ? >> > Yes, this would be a postgresql jdbc driver specific escape. The spec > doesn't have a concept of private escape sequences, but that doesn't seem > like the end of the world. Clearly the user here is writing postgresql > specific code to use hstore operators, so there's not a portability loss > here. > I assume, though, that you're not talking about something that's hstore-specific, but rather something that will allow the user to put a non-parameter question mark in the query string. As has been noted upthread, the hstore use is far from the only one that causes users to trip on this. cheers andrew
That would seem to be the implication. JDBC wouldn't really know anything about hstore.
On Fri, Feb 8, 2013 at 12:51 PM, Andrew Dunstan <andrew@dunslane.net> wrote:
I assume, though, that you're not talking about something that's hstore-specific, but rather something that will allow the user to put a non-parameter question mark in the query string. As has been noted upthread, the hstore use is far from the only one that causes users to trip on this.
On 02/08/2013 12:41 PM, Kris Jurka wrote:
On Fri, 8 Feb 2013, Dave Cramer wrote:Would this be an postgresql specific escape sequence ? I don't think theYes, this would be a postgresql jdbc driver specific escape. The spec
spec allows for this does it ?
doesn't have a concept of private escape sequences, but that doesn't seem
like the end of the world. Clearly the user here is writing postgresql
specific code to use hstore operators, so there's not a portability loss
here.
cheers
andrew
The thing is PostgeSQL JDBC driver should be able to parse sql in order to tell if specific question mark is a bind variable or it is inside string literal, or it is inside of some comment.
I do not believe JDBC spec forces to treat all ? as bind placeholders. That's unusable.
Oracle JDBC allows having ? symbols in comments and string literals without any special escapement.
08.02.2013 22:01 пользователь "Dave Cramer" <pg@fastcrypt.com> написал:
That would seem to be the implication. JDBC wouldn't really know anything about hstore.On Fri, Feb 8, 2013 at 12:51 PM, Andrew Dunstan <andrew@dunslane.net> wrote:I assume, though, that you're not talking about something that's hstore-specific, but rather something that will allow the user to put a non-parameter question mark in the query string. As has been noted upthread, the hstore use is far from the only one that causes users to trip on this.
On 02/08/2013 12:41 PM, Kris Jurka wrote:
On Fri, 8 Feb 2013, Dave Cramer wrote:Would this be an postgresql specific escape sequence ? I don't think theYes, this would be a postgresql jdbc driver specific escape. The spec
spec allows for this does it ?
doesn't have a concept of private escape sequences, but that doesn't seem
like the end of the world. Clearly the user here is writing postgresql
specific code to use hstore operators, so there's not a portability loss
here.
cheers
andrew
Vladimir Sitnikov <sitnikov.vladimir@gmail.com> writes: > The thing is PostgeSQL JDBC driver should be able to parse sql in order to > tell if specific question mark is a bind variable or it is inside string > literal, or it is inside of some comment. What's your point? Those cases don't have anything to do with variables versus operators, neither of which would be inside a literal or comment. It would take extremely deep knowledge of SQL syntax for the driver to reliably tell the difference between a variable and an operator --- and even then, I'm not sure it'd be terribly user-friendly, because the parsing would depend on details like where there is whitespace. For instance, the backend parser would think that "?= 2" is a prefix operator named "?=" followed by literal 2, whereas "? = 2" will be parsed differently, and "? ? 2" yet differently (because "=" is special-cased but an operator named "?" isn't). I'm not sure it'd be any more usable to work like that than with an explicit escaping convention. regards, tom lane
On 2/11/13 11:30 AM, Tom Lane wrote: > It would take extremely deep knowledge of SQL syntax for the driver to > reliably tell the difference between a variable and an operator Yes, auto-detecting the difference between bind vars and operators would probably be even more difficult than providing escapes for ?, the difficulty of which Kris pointed out earlier: On 2/8/13 at 10:43AM Kris Jurka wrote: > This will be more complicated than you might hope because the escape processing currently happens prior to bind parameterdetection The relevant section, I believe, is: https://github.com/pgjdbc/pgjdbc/blob/master/org/postgresql/core/v3/QueryExecutorImpl.java#L164 Best, Seamus PS. Thanks Andrew for reminding me about top-posting :)
On 08.02.2013 19:41, Kris Jurka wrote: > On Fri, 8 Feb 2013, Dave Cramer wrote: > >> Would this be an postgresql specific escape sequence ? I don't think the >> spec allows for this does it ? >> > > Yes, this would be a postgresql jdbc driver specific escape. The spec > doesn't have a concept of private escape sequences, but that doesn't seem > like the end of the world. Clearly the user here is writing postgresql > specific code to use hstore operators, so there's not a portability loss > here. I agree it's pretty dumb that there's currently no such escape. I think JDBC inherited that design mistake from ODBC. Fixing that would be a good idea. That said, it occurs to me that there's one fairly simple thing we could also do in the backend. At the moment, unlike function and table names, operators cannot be quoted. It would be easy to allow this in the grammar: select 1 operator("+") 1; The operator(...) syntax already exists, but the operator inside it can't be quoted. It wouldn't create any conflicts to allow that. - Heikki
On 2/11/13 1:35 PM, Heikki Linnakangas wrote: > I agree it's pretty dumb that there's currently no such escape. I think JDBC inherited that design mistake from ODBC. Fixingthat would be a good idea. Lance Anderson, Oracle's JDBC spec lead, says [1] we can implement something like: SELECT * FROM tbl WHERE data {postgres qm} 'abc' Thanks to Mark Rotteveel for driving the discussion. [2] > That said, it occurs to me that there's one fairly simple thing we could also do in the backend. At the moment, unlikefunction and table names, operators cannot be quoted. It would be easy to allow this in the grammar: > > select 1 operator("+") 1; I guess I see 2 simple options and 1 complex option: a) [simple] operator("+") per Heikki b) [simple, but not popular] alias ? to ~ per Seamus c) [complex] {postgres blah} per Lance/Mark How to decide? Best, Seamus [1] http://mail.openjdk.java.net/pipermail/jdbc-spec-discuss/2013-February/000058.html [2] http://mail.openjdk.java.net/pipermail/jdbc-spec-discuss/2013-February/date.html#51 (threaded view gets it out of order) -- Seamus Abshere seamus@abshere.net https://github.com/seamusabshere
Since we already do escape processing much like c that might not be so complex. However I haven't looked at the code, so I could be way off base.
The question I would pose is how palatable is it to use ? In other words is it worth pursuing ?
On Wed, Feb 13, 2013 at 12:10 PM, Seamus Abshere <seamus@abshere.net> wrote:
On 2/11/13 1:35 PM, Heikki Linnakangas wrote:Lance Anderson, Oracle's JDBC spec lead, says [1] we can implement something like:I agree it's pretty dumb that there's currently no such escape. I think JDBC inherited that design mistake from ODBC. Fixing that would be a good idea.
SELECT * FROM tbl WHERE data {postgres qm} 'abc'
Thanks to Mark Rotteveel for driving the discussion. [2]I guess I see 2 simple options and 1 complex option:That said, it occurs to me that there's one fairly simple thing we could also do in the backend. At the moment, unlike function and table names, operators cannot be quoted. It would be easy to allow this in the grammar:
select 1 operator("+") 1;
a) [simple] operator("+") per Heikki
b) [simple, but not popular] alias ? to ~ per Seamus
c) [complex] {postgres blah} per Lance/Mark
How to decide?
Best,
Seamus
[1] http://mail.openjdk.java.net/pipermail/jdbc-spec-discuss/2013-February/000058.html
[2] http://mail.openjdk.java.net/pipermail/jdbc-spec-discuss/2013-February/date.html#51 (threaded view gets it out of order)
Seamus Abshere escribió: > [1] http://mail.openjdk.java.net/pipermail/jdbc-spec-discuss/2013-February/000058.html > [2] http://mail.openjdk.java.net/pipermail/jdbc-spec-discuss/2013-February/date.html#51 > (threaded view gets it out of order) Ooh, how archaic --- they're still using Mhonarc to webify list archives! ;-) -- Álvaro Herrera http://www.2ndQuadrant.com/ PostgreSQL Development, 24x7 Support, Training & Services
<p dir="ltr"><br /> On Feb 13, 2013 6:43 PM, "Alvaro Herrera" <<a href="mailto:alvherre@2ndquadrant.com">alvherre@2ndquadrant.com</a>>wrote:<br /> ><br /> > Seamus Abshere escribió:<br/> ><br /> > > [1] <a href="http://mail.openjdk.java.net/pipermail/jdbc-spec-discuss/2013-February/000058.html">http://mail.openjdk.java.net/pipermail/jdbc-spec-discuss/2013-February/000058.html</a><br />> > [2] <a href="http://mail.openjdk.java.net/pipermail/jdbc-spec-discuss/2013-February/date.html#51">http://mail.openjdk.java.net/pipermail/jdbc-spec-discuss/2013-February/date.html#51</a><br />> > (threaded view gets it out of order)<br /> ><br /> > Ooh, how archaic --- they're still using Mhonarc towebify list<br /> > archives! ;-)<br /><p dir="ltr">From the url, it certainly looks more like pipermail... <p dir="ltr">/Magnus<br />
Seamus Abshere <seamus@abshere.net> wrote: > On 2/11/13 1:35 PM, Heikki Linnakangas wrote: >> I agree it's pretty dumb that there's currently no such escape. >> I think JDBC inherited that design mistake from ODBC. Fixing >> that would be a good idea. > > Lance Anderson, Oracle's JDBC spec lead Wow, there's a name I haven't seen in years. I used to deal with him often when he was at Sybase, and once or twice after he moved to Sun. Sharp guy. > says we can implement something like: > > SELECT * FROM tbl WHERE data {postgres qm} 'abc' That suggestion makes a lot of sense to me. The curly-brace escapes are in JDBC for portability, so this seems like a totally appropriate use; it's surprising it hasn't come up before. > I guess I see 2 simple options and 1 complex option: > > a) [simple] operator("+") per Heikki > b) [simple, but not popular] alias ? to ~ per Seamus > c) [complex] {postgres blah} per Lance/Mark > > How to decide? We already have code in the JDBC driver to recognize curly-brace escape sequences. We just need to add "postgres" as another keyword for such escapes and we can do what we like for the rest of the escape sequence. A mnemonic, such as Lance suggests, does seem like a good approach. -- Kevin Grittner EnterpriseDB: http://www.enterprisedb.com The Enterprise PostgreSQL Company
On 13.02.2013 22:17, Kevin Grittner wrote: > Seamus Abshere<seamus@abshere.net> wrote: >> SELECT * FROM tbl WHERE data {postgres qm} 'abc' > > That suggestion makes a lot of sense to me. The curly-brace > escapes are in JDBC for portability, so this seems like a totally > appropriate use; it's surprising it hasn't come up before. +1 for something like this. Rather than a straight "{postgres qm}" to represent a question mark, though, perhaps it would be more readable to allow something like this though: {postgres SELECT * FROM tbl WHERE data ? 'abc' AND column = $1} Ie. within "{postgres ... }", ? means a question mark, not a parameter marker, and for parameter markers, you use the PostgreSQL syntax, $n. Also, should we consider how to escape { and } characters? They're not a problem at the moment, but while we're at it... >> I guess I see 2 simple options and 1 complex option: >> >> a) [simple] operator("+") per Heikki >> b) [simple, but not popular] alias ? to ~ per Seamus >> c) [complex] {postgres blah} per Lance/Mark >> >> How to decide? > > We already have code in the JDBC driver to recognize curly-brace > escape sequences. We just need to add "postgres" as another > keyword for such escapes and we can do what we like for the rest of > the escape sequence. A mnemonic, such as Lance suggests, does seem > like a good approach. We could support operator("?") as well; belt and suspenders. That would help ODBC clients too. - Heikki
<p dir="ltr"><br /> On Feb 13, 2013 10:35 PM, "Heikki Linnakangas" <<a href="mailto:hlinnakangas@vmware.com">hlinnakangas@vmware.com</a>>wrote:<br /> > We could support operator("?") aswell; belt and suspenders. That would help ODBC clients too.<p dir="ltr">+1 for the belt and suspenders approach. With{postgres qm} JDBC can work with older PostgreSQL versions, not requiring applications to bump their minimum db version.With operator("?") older JDBC clients can work too in case the library version is fixed due to policies (I'm assuminghere that question marks already work within quoted identifiers/literals).<p dir="ltr">--<br /> Ants Aasma