Shantanu's Blog

Database Consultant

April 20, 2005

 

MySQL Case Study - 9

Composite Primary Key explained:

> Hi there, I was wondering how its possible to get the MAX of a primary
> key of a table during an insert. I basically want to create a ticket
> number, but use the primary key as part of the ticket number ie
> FAULT-0000001 or FAULT-00000002 . I tried during a sub query on an
> insert but obviouslly not working :|
>
> Let me know.
>
>

It sounds like you are generating primary keys based on some letters + an
incrementing value. That is a very user-friendly method but does not lend
itself well to MySQL. What you CAN do with mysql is to split your primary
key into two columns, one text the other an auto_increment-ed numeric.
Then, when you insert the new row of data you can use LAST_INSERT_ID() to
get the numeric value assigned to the new row.

http://dev.mysql.com/doc/mysql/en/example-auto-increment.html
http://dev.mysql.com/doc/mysql/en/information-functions.html

A demonstration might be useful:

CREATE TABLE `IncidentData` (
`IncidentType` varchar(8) NOT NULL default '',
`TypeSerial` int(10) unsigned NOT NULL auto_increment,
`... other columns here ...` varchar(255) default NULL,
PRIMARY KEY (`IncidentType`,`TypeSerial`)
);

Now to give it some base data. I will create 3 "fault" incidents, 2
"warning" incidents, and 4 "request" incidents in random order:

INSERT IncidentData (IncidentType, `... other columns here ...`)
VALUES ('request','... other column data ...')
,('warning','... other column data ...')
,('warning','... other column data ...')
,('fault','... other column data ...')
,('request','... other column data ...')
,('fault','... other column data ...')
,('request','... other column data ...')
,('request','... other column data ...')
,('fault','... other column data ...');

(Notice that I _did not_ INSERT any data into the TypeSerial column. This
was intentional as I wanted to demonstrate the group-wise auto_increment
feature.)

Now let's see what the table looks like:

localhost.test>SELECT * from IncidentData;
+--------------+------------+----------------------------+
| IncidentType | TypeSerial | ... other columns here ... |
+--------------+------------+----------------------------+
| request | 1 | ... other column data ... |
| warning | 1 | ... other column data ... |
| warning | 2 | ... other column data ... |
| fault | 1 | ... other column data ... |
| request | 2 | ... other column data ... |
| fault | 2 | ... other column data ... |
| request | 3 | ... other column data ... |
| request | 4 | ... other column data ... |
| fault | 3 | ... other column data ... |
+--------------+------------+----------------------------+
9 rows in set (0.00 sec)

Now, assume you need to add a new "fault" type incident to this table and
link some rows in another table to it. To do that you need the PK (as you
already said) of the new row. Fortunately you already know HALF of the key
(what type of incident you are creating). What you need is the other half,
the auto_incremented number. That's where LAST_INSERT_ID() comes in

INSERT IncidentData (IncidentType, `... other columns here ...`
VALUES ('fault','... new record column data ...');

SELECT LAST_INSERT_ID();
+------------------+
| last_insert_id() |
+------------------+
| 4 |
+------------------+
1 row in set (0.00 sec)

Which is the last auto_increment value issued to your connection. As long
as you are entering records one at a time, it will represent the numeric
half of the PK for the last row you entered. Check it if you don't believe
me:

SELECT * from IncidentData;
+--------------+------------+--------------------------------+
| IncidentType | TypeSerial | ... other columns here ... |
+--------------+------------+--------------------------------+
| request | 1 | ... other column data ... |
| warning | 1 | ... other column data ... |
| warning | 2 | ... other column data ... |
| fault | 1 | ... other column data ... |
| request | 2 | ... other column data ... |
| fault | 2 | ... other column data ... |
| request | 3 | ... other column data ... |
| request | 4 | ... other column data ... |
| fault | 3 | ... other column data ... |
| fault | 4 | ... new record column data ... |
+--------------+------------+--------------------------------+
10 rows in set (0.00 sec)

So the PK of your new row is ('fault',4) and that's what you use as the FK
value(s) on your child table (since you have a two column PK on your
parent table, you need two FK columns on any of its child tables to hold
the value) . So far so good? However you want to present the data as
XXXXX-0000000. That is now reduced to a simple formatting issue that can
be solved either on your front end or with a query like:

SELECT CONCAT(UCASE(IncidentType),'-',LPAD(TypeSerial,8,'0')) as Serial
, IncidentType
, TypeSerial
FROM IncidentData;
+------------------+--------------+------------+
| Serial | IncidentType | TypeSerial |
+------------------+--------------+------------+
| FAULT-00000001 | fault | 1 |
| FAULT-00000002 | fault | 2 |
| FAULT-00000003 | fault | 3 |
| FAULT-00000004 | fault | 4 |
| REQUEST-00000001 | request | 1 |
| REQUEST-00000002 | request | 2 |
| REQUEST-00000003 | request | 3 |
| REQUEST-00000004 | request | 4 |
| WARNING-00000001 | warning | 1 |
| WARNING-00000002 | warning | 2 |
+------------------+--------------+------------+
10 rows in set (0.00 sec)

Does that help with your problem?

**ALSO, splitting the type of the incident and the serial number into
separate columns will help you to isolate certain types of incidents
without resorting to substring analyses. Since the IncidentType is the
left-most column in the PK, this query is blazingly fast

SELECT ...
FROM IncidentData
WHERE IncidentType = 'fault';

whereas if you had left it as a combined text field you would have had to
do something like

SELECT ...
FROM IncidentData
WHERE IncidentType LIKE 'fault-%';

Which is not nearly as quick (especially for larger tables);

Comments: Post a Comment

<< Home

Archives

June 2001   July 2001   January 2003   May 2003   September 2003   October 2003   December 2003   January 2004   February 2004   March 2004   April 2004   May 2004   June 2004   July 2004   August 2004   September 2004   October 2004   November 2004   December 2004   January 2005   February 2005   March 2005   April 2005   May 2005   June 2005   July 2005   August 2005   September 2005   October 2005   November 2005   December 2005   January 2006   February 2006   March 2006   April 2006   May 2006   June 2006   July 2006   August 2006   September 2006   October 2006   November 2006   December 2006   January 2007   February 2007   March 2007   April 2007   June 2007   July 2007   August 2007   September 2007   October 2007   November 2007   December 2007   January 2008   February 2008   March 2008   April 2008   July 2008   August 2008   September 2008   October 2008   November 2008   December 2008   January 2009   February 2009   March 2009   April 2009   May 2009   June 2009   July 2009   August 2009   September 2009   October 2009   November 2009   December 2009   January 2010   February 2010   March 2010   April 2010   May 2010   June 2010   July 2010   August 2010   September 2010   October 2010   November 2010   December 2010   January 2011   February 2011   March 2011   April 2011   May 2011   June 2011   July 2011   August 2011   September 2011   October 2011   November 2011   December 2011   January 2012   February 2012   March 2012   April 2012   May 2012   June 2012   July 2012   August 2012   October 2012   November 2012   December 2012   January 2013   February 2013   March 2013   April 2013   May 2013   June 2013   July 2013   September 2013   October 2013   January 2014   March 2014   April 2014   May 2014   July 2014   August 2014   September 2014   October 2014   November 2014   December 2014   January 2015   February 2015   March 2015   April 2015   May 2015   June 2015   July 2015   August 2015   September 2015   January 2016   February 2016   March 2016   April 2016   May 2016   June 2016   July 2016   August 2016   September 2016   October 2016   November 2016   December 2016   January 2017   February 2017   April 2017   May 2017   June 2017   July 2017   August 2017   September 2017   October 2017   November 2017   December 2017   February 2018   March 2018   April 2018   May 2018   June 2018   July 2018   August 2018   September 2018   October 2018   November 2018   December 2018   January 2019   February 2019   March 2019   April 2019   May 2019   July 2019   August 2019   September 2019   October 2019   November 2019   December 2019   January 2020   February 2020   March 2020   April 2020   May 2020   July 2020   August 2020   September 2020   October 2020   December 2020   January 2021   April 2021   May 2021   July 2021   September 2021   March 2022   October 2022   November 2022   March 2023   April 2023   July 2023   September 2023   October 2023   November 2023  

This page is powered by Blogger. Isn't yours?