Thread: INSERT ... SELECT problem in Mysql
Hi! I was trying to port a solution from postgresql to mysql for a mysql user. im often using INSERT ... SELECTS with the same table in the INSERT and SELECT statments at the same time. In Postgres i used to use the destination only in a Subquery with IN, but in Mysql i had to join the table, but it didn´t work and threw this error : INSERT TABLE 'dummy' isn't allowed in FROM table list with this page explaining the error : http://www.mysql.de/doc/en/INSERT_SELECT.html I have a problem with this part in the text ---- The target table of the INSERT statement cannot appear in the FROM clause of the SELECT part of the query because it's forbiddenin standard SQL to SELECT from the same table into which you are inserting. (The problem is that the SELECT possiblywould find records that were inserted earlier during the same run. When using subquery clauses, the situation couldeasily be very confusing!) ---- Is that correct? PostgreSQL allows this which is very handy, but breaks so some ANSI compliance. Can anyform that ANSI SQL doesn´t allow this? Thanx Christoph Nelles -- Mit freundlichen Grüssen Evil Azrael mailto:evilazrael@evilazrael.de
Evil Azrael <evilazrael@evilazrael.de> writes: > I have a problem with this part in the text > ---- > The target table of the INSERT statement cannot appear in the FROM > clause of the SELECT part of the query because it's forbidden in > standard SQL to SELECT from the same table into which you are > inserting. This is just MySQL's self-serving reading of the spec. What SQL92 actually says is (section 13.8) 1) The following restrictions apply for Intermediate SQL: a) The leaf generally underlying table of T shall not be gen- erally contained in the <query expression>immediately contained in the <insert columns and source> except as the <qualifier> ofa <column reference>. SQL99 puts it a little differently: Conformance Rules 1) Without Feature F781, "Self-referencing operations", no leaf generally underlying table of T shall begenerally contained in the <query expression> immediately contained in the <insert columns and source>except as the <table or query name> or <correlation name> of a column reference. In other words, the behavior is perfectly standard, it's just not required for minimal SQL implementations to support it. What the standard behavior is is defined by this rule, earlier in the same section: 3) The <query expression> is effectively evaluated before inserting any rows into B. that is, the SELECT doesn't see any rows that are being inserted into the target table during the same command. There would not be any need for that rule if selecting from the same table you're inserting into were flat-out forbidden, as the MySQL docs claim. regards, tom lane
Thanx for the fast answer. I already thought something about like this and considered sending the question to the advocacy list instead of the SQL list. I really like their docs since iŽve read about their reasons against Foreign Keys *g* One more point in favor for PostgreSQL :) Christoph Nelles Am Freitag, 4. Juli 2003 um 23:45 schrieben Sie: TL> Evil Azrael <evilazrael@evilazrael.de> writes: >> I have a problem with this part in the text >> ---- >> The target table of the INSERT statement cannot appear in the FROM >> clause of the SELECT part of the query because it's forbidden in >> standard SQL to SELECT from the same table into which you are >> inserting. TL> This is just MySQL's self-serving reading of the spec. What SQL92 TL> actually says is (section 13.8) TL> 1) The following restrictions apply for Intermediate SQL: TL> a) The leaf generally underlying table of T shall not be gen- TL> erally contained in the <query expression> immediately TL> contained in the <insert columns and source> except as the TL> <qualifier> of a <column reference>. TL> SQL99 puts it a little differently: TL> Conformance Rules TL> 1) Without Feature F781, "Self-referencing operations", no leaf TL> generally underlying table of T shall be generally contained in TL> the <query expression> immediately contained in the <insert TL> columns and source> except as the <table or query name> or TL> <correlation name> of a column reference. TL> In other words, the behavior is perfectly standard, it's just not TL> required for minimal SQL implementations to support it. TL> What the standard behavior is is defined by this rule, earlier in the TL> same section: TL> 3) The <query expression> is effectively evaluated before inserting TL> any rows into B. TL> that is, the SELECT doesn't see any rows that are being inserted into TL> the target table during the same command. There would not be any need TL> for that rule if selecting from the same table you're inserting into TL> were flat-out forbidden, as the MySQL docs claim. TL> regards, tom lane -- Mit freundlichen Grüssen Evil Azrael mailto:evilazrael@evilazrael.de
On Saturday 05 July 2003 00:06, Evil Azrael wrote: > Thanx for the fast answer. I already thought something about like > this and considered sending the question to the advocacy list instead > of the SQL list. I really like their docs since iŽve read about their > reasons against Foreign Keys *g* > > One more point in favor for PostgreSQL :) I've been here before, this thread: http://archives.postgresql.org/pgsql-sql/2003-04/msg00159.php might be of interest. Ian Barwick barwick@gmx.net