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);