Brilliant, many thanks for the heads up :-) On Wed, May 20, 2015 at 4:07 PM, Lukas Eder <[email protected]> wrote: > Oh, I see. You may have misunderstood how jOOQ's templating works. {0} and > {1} are placeholders for QueryParts, not for SQL strings. So just plug your > complete org.jooq.Query object in there. Changes in yellow: > > Field<String> allocated = ALLOCATIONS.NUMBER.min().as("allocated"); > > String number = db.execute(ctx -> { > > Query query = ctx.insertInto(PRIMARY_ASSIGNMENTS, > PRIMARY_ASSIGNMENTS.REGISTRANT, PRIMARY_ASSIGNMENTS.NUMBER). > select( > ctx.select(DSL.val(registrant), allocated). > from(ALLOCATIONS). > where(ALLOCATIONS.NUMBER.notIn( > ctx.select(ASSIGNMENTS.NUMBER). > from(ASSIGNMENTS) > ).and(ALLOCATIONS.REGISTRANT.eq(registrant))) > ); > > return ctx.fetch("{0} RETURNING {1}", query, allocated).getValue(1, > allocated); > }); > > > That way, the bind variables will stay in place where they belong. > > There are some examples here: > > - > http://www.jooq.org/doc/latest/manual/sql-building/queryparts/plain-sql-queryparts > - > http://www.jooq.org/javadoc/latest/org/jooq/DSLContext.html#fetch-java.lang.String-org.jooq.QueryPart...- > > Specifically, the Javadoc: > > Execute a new query holding plain SQL. > > Unlike fetch(String, Object...), the SQL passed to this method should not > contain any bind variables. Instead, you can pass QueryPart objects to the > method which will be rendered at indexed locations of your SQL string as > such: > > // The following query > > fetch("select {0}, {1} from {2}", val(1), inline("test"), name("DUAL")); > > // Will execute this SQL on an Oracle database with RenderNameStyle.QUOTED: > > select ?, 'test' from "DUAL" > > Hope this helps, > Lukas > > 2015-05-20 16:50 GMT+02:00 Ben Hood <[email protected]>: >> >> Ah that sounds like a good tip (there I was hacking away at a proc). >> >> So I've re-formulated it like this: >> >> Field<String> allocated = ALLOCATIONS.NUMBER.min().as("allocated"); >> >> String number = db.execute(ctx -> { >> >> String sql = ctx.insertInto(PRIMARY_ASSIGNMENTS, >> PRIMARY_ASSIGNMENTS.REGISTRANT, PRIMARY_ASSIGNMENTS.NUMBER). >> select( >> ctx.select(DSL.val(registrant), allocated). >> from(ALLOCATIONS). >> where(ALLOCATIONS.NUMBER.notIn( >> ctx.select(ASSIGNMENTS.NUMBER). >> from(ASSIGNMENTS) >> ).and(ALLOCATIONS.REGISTRANT.eq(registrant))) >> ).getSQL(); >> >> return ctx.fetch("{0} RETURNING {1}", sql, >> allocated.getName()).getValue(1, allocated); >> }); >> >> But I seem to be getting a binding error: >> >> SQL [? RETURNING ?]; ERROR: syntax error at or near "$1" >> >> Am I forgetting to bind the query parameters somewhere? >> >> >> On Wed, May 20, 2015 at 3:31 PM, Lukas Eder <[email protected]> wrote: >> > Yes, but you don't have to do everything with plain SQL. You can do >> > this: >> > >> > DSL.using(configuration) >> > .fetch("{0} returning {1}", theSelect, theField); >> > >> > >> > 2015-05-20 16:23 GMT+02:00 Ben Hood <[email protected]>: >> >> >> >> Hi Lukas, >> >> >> >> Good to know that a fix in the pipeline - I guess for now I should >> >> just write this query in plain SQL? >> >> >> >> Ben >> >> >> >> On Wed, May 20, 2015 at 3:17 PM, Lukas Eder <[email protected]> >> >> wrote: >> >> > Hi Ben, >> >> > >> >> > Yes, that's too bad. The INSERT .. SELECT API has a couple of flaws. >> >> > This >> >> > particular flaw, I've just fixed recently for jOOQ 3.7: >> >> > https://github.com/jOOQ/jOOQ/issues/3779 >> >> > >> >> > Unfortunately, it won't be available for earlier versions... >> >> > >> >> > Cheers, >> >> > Lukas >> >> > >> >> > 2015-05-20 16:13 GMT+02:00 Ben Hood <[email protected]>: >> >> >> >> >> >> Hi Lukas, >> >> >> >> >> >> I can't seem to find the API to do an INSERT RETURNING using a >> >> >> SELECT, >> >> >> for example: >> >> >> >> >> >> db.execute(ctx -> >> >> >> ctx.insertInto(PRIMARY_ASSIGNMENTS, >> >> >> PRIMARY_ASSIGNMENTS.REGISTRANT, >> >> >> PRIMARY_ASSIGNMENTS.NUMBER). >> >> >> select( >> >> >> ctx.select(DSL.val(registrant), ALLOCATIONS.NUMBER.min()). >> >> >> from(ALLOCATIONS). >> >> >> where(ALLOCATIONS.NUMBER.notIn( >> >> >> ctx.select(ASSIGNMENTS.NUMBER). >> >> >> from(ASSIGNMENTS) >> >> >> ).and(ALLOCATIONS.REGISTRANT.eq(registrant))) >> >> >> ). >> >> >> execute() >> >> >> ); >> >> >> >> >> >> I was poking for some kind of returning() thingy, as you can use on >> >> >> a >> >> >> InsertValuesStepN. >> >> >> >> >> >> Or is it more idiomatic to do a plain jane >> >> >> >> >> >> ctx.insertInto(). >> >> >> values( >> >> >> ctx.select().stuff().here()). >> >> >> returning( >> >> >> field().from().stuff() >> >> >> ) >> >> >> >> >> >> ? >> >> >> >> >> >> Cheers, >> >> >> >> >> >> Ben >> >> >> >> >> >> -- >> >> >> You received this message because you are subscribed to the Google >> >> >> Groups >> >> >> "jOOQ User Group" group. >> >> >> To unsubscribe from this group and stop receiving emails from it, >> >> >> send >> >> >> an >> >> >> email to [email protected]. >> >> >> For more options, visit https://groups.google.com/d/optout. >> >> > >> >> > >> >> > -- >> >> > You received this message because you are subscribed to the Google >> >> > Groups >> >> > "jOOQ User Group" group. >> >> > To unsubscribe from this group and stop receiving emails from it, >> >> > send >> >> > an >> >> > email to [email protected]. >> >> > For more options, visit https://groups.google.com/d/optout. >> >> >> >> -- >> >> You received this message because you are subscribed to the Google >> >> Groups >> >> "jOOQ User Group" group. >> >> To unsubscribe from this group and stop receiving emails from it, send >> >> an >> >> email to [email protected]. >> >> For more options, visit https://groups.google.com/d/optout. >> > >> > >> > -- >> > You received this message because you are subscribed to the Google >> > Groups >> > "jOOQ User Group" group. >> > To unsubscribe from this group and stop receiving emails from it, send >> > an >> > email to [email protected]. >> > For more options, visit https://groups.google.com/d/optout. >> >> -- >> You received this message because you are subscribed to the Google Groups >> "jOOQ User Group" group. >> To unsubscribe from this group and stop receiving emails from it, send an >> email to [email protected]. >> For more options, visit https://groups.google.com/d/optout. > > > -- > You received this message because you are subscribed to the Google Groups > "jOOQ User Group" group. > To unsubscribe from this group and stop receiving emails from it, send an > email to [email protected]. > For more options, visit https://groups.google.com/d/optout.
-- You received this message because you are subscribed to the Google Groups "jOOQ User Group" group. To unsubscribe from this group and stop receiving emails from it, send an email to [email protected]. For more options, visit https://groups.google.com/d/optout.
