![]() |
|
more useful options | |
PerlMonks |
Re^4: SELECT LAST_INSERT_ID does not workby afoken (Chancellor) |
on Jun 30, 2017 at 20:55 UTC ( #1193953=note: print w/replies, xml ) | Need Help?? |
My problem with LAST_INSERT_ID is that it is not well-defined. https://dev.mysql.com/doc/refman/5.7/en/getting-unique-id.html starts with a definiton and links to more information: For LAST_INSERT_ID(), the most recently generated ID is maintained in the server on a per-connection basis. It is not changed by another client. It is not even changed if you update another AUTO_INCREMENT column with a nonmagic value (that is, a value that is not NULL and not 0). Using LAST_INSERT_ID() and AUTO_INCREMENT columns simultaneously from multiple clients is perfectly valid. Each client will receive the last inserted ID for the last statement that client executed. So far, so good. We don't have to worry about parallel access from different clients, that piece of data is stored per connection. Inserting values different from NULL and 0 into an AUTO_INCREMENT column does not change the data. That may be a little bit surprising, but it should be easy to handle. And we get the last generated ID. Linked from there, we can find https://dev.mysql.com/doc/refman/5.7/en/information-functions.html#function_last-insert-id. Unfortunately, it documents a significantly different behaviour: With no argument, LAST_INSERT_ID() returns a BIGINT UNSIGNED (64-bit) value representing the first automatically generated value successfully inserted for an AUTO_INCREMENT column as a result of the most recently executed INSERT statement. And this is even repeated in an "Important" block: If you insert multiple rows using a single INSERT statement, LAST_INSERT_ID() returns the value generated for the first inserted row only. The reason for this is to make it possible to reproduce easily the same INSERT statement against some other server. We get the first generated ID for an INSERT statement, not the last one. Wouldn't it be nice to have a documentation that does not contradict itself? Also documented there:
So changes to the last ID value are persistent from stored procedures, but not from stored functions and triggers. https://dev.mysql.com/doc/refman/5.7/en/mysql-insert-id.html, linked from the first document, documents once again that the first ID is stored, not the last one: In the case of a multiple-row INSERT statement, mysql_insert_id() returns the first automatically generated AUTO_INCREMENT value that was successfully inserted. But only a few lines later, the something very different is documented:
So the last-insert-id value is overwritten by explicit values, according to that page. I originally wanted to read the two other pages linked from the first document, but I'm getting sick of MySQL. Just for fun, let's have a look at PostgreSQL: PostgreSQL has the pseudo-types SERIAL and BIGSERIAL that really are INTEGER and BIGINT, combined with an implicit NOT NULL constraint and a DEFAULT clause referencing to an automatically created sequence: https://www.postgresql.org/docs/9.1/static/datatype-numeric.html#DATATYPE-SERIAL (This is a link to an older 9.x series documentation, but I know that mechanism is available since at least the 8.x series). Getting the last inserted value is easy: Either explicitly query the sequence for the current value inside a transaction, or even shorter, use the extended INSERT syntax INSERT INTO table .... RETURNING idcolumn, as documented in https://www.postgresql.org/docs/9.1/static/sql-insert.html. DBD::Pg implements last_insert_id() by querying the database for the sequence name and its current value. The INSERT ... RETURNING way is unfortunately not portable, but it is the cleanest aproach to return an automatically generated ID that I know. A quick look at Oracle. The documentation for last_insert_id in DBD::Oracle is very clear: Oracle does not have anything like SERIAL or AUTO_INCREMENT. You need to manually use a sequence. You can read the sequence value from within the INSERT statement, and, similar to PostgreSQL, you can extend the INSERT statement to return the inserted value (using RETURNING). An other way to implement an automatic IDs is to create a trigger on the table that overwrites the ID column with a sequence value. This was the way that I learned while learning to use Oracle. Later, I wrote (perl) code to first fetch the next value from a sequence, then use that value for an INSERT statement. That way, I knew the inserted ID even before actually inserting it. I'm quite sure that the INSERT ... RETURNING statement was not in the DBD::Oracle documentation 15 years ago, or else I would have used that instead. MS SQL Server uses INTEGER IDENTITY to create automatic IDs, you have to read them using SELECT @@IDENTITY. Triggers may mess with the returned value. (https://docs.microsoft.com/en-us/sql/t-sql/functions/identity-transact-sql) Overall, quite similar to MySQL. Update: erix suggested to change the PostgreSQL documentation links from 9.1 to current, i.e. https://www.postgresql.org/docs/current/static/datatype-numeric.html#DATATYPE-SERIAL and https://www.postgresql.org/docs/current/static/sql-insert.html. Well, yes, it could be useful, but my intention was to document old behaviour, not current, even if both are currently equal (at 9.6). So I linked to 9.1, and the links will stay that way. Maybe I should have linked to 8.2 instead, so here you are: https://www.postgresql.org/docs/8.2/static/datatype-numeric.html#DATATYPE-SERIAL and https://www.postgresql.org/docs/8.2/static/sql-insert.html Alexander
-- Today I will gladly share my knowledge and experience, for there are no sweeter words than "I told you so". ;-)
In Section
Seekers of Perl Wisdom
|
|