
While I’m switching labs next term after more than a decade with more comprehensive lab set, I’m hoping the new exercises build the students’ core SQL skill set. Next term, I hope to see whether the change is successful. I’ve opted for using Alan Beaulieu’s Learning SQL: Generate, Manipulate, and Retrieve Data, 3rd Edition, because it’s a great book and uses the MySQL database.
One exercise that the students will lose is a data migration exercise from a badly designed common_lookup table to a well designed common_lookup table. The starting point is shown below on the left and the fixed version is on the right.
There are several problems with the original common_lookup table’s design. The first problem is that the common_lookup_context column does not uniquely identify a location within the data model for at least one list of lookup values. While it uses table names generally, it has no way to support two or more lists within the same table. It also uses a 'MULTIPLE' string for a list of values that supports two tables. The two tables supported by 'MULTIPLE' string are the address and telephone tables.
The lab instructions have the students add the following three columns to the table:
common_lookup_tablecommon_lookup_columncommon_lookup_code
Together the combination of the common_lookup_table and common_lookup_column columns create a non-unique super key. The super keyidentifies micro subtables. The combination of the common_lookup_table, common_lookup_column, and common_lookup_type columns creates a unique natural key that defines all possible values for a lookup list based on a column in a table.
The lab asked the students to use the existing data, string literal values, and some simple rules to populate the new common_lookup_table and common_lookup_column columns with data. The rules or steps were:
- Migrate valid table names from the
common_lookup_contextcolumn to thecommon_lookup_tablecolumn. - Migrate a literal
'ADDRESS'value into thecommon_lookup_tablecolumn when thecommon_lookup_contextcolumn holds a'MULTIPLE'string value. - Migrate valid table names from the
common_lookup_contextcolumn to thecommon_lookup_columncolumn by appending a'_TYPE'string literal to thecommon_lookup_contextcolumn values, except for those three rows that have a ‘VISA_CARD’, ‘MASTER_CARD’, or ‘DISCOVER_CARD’. The three exempted rows should update thecommon_lookup_columncolumn with a'CREDIT_CARD_TYPE'string literal. - Migrate a literal
'ADDRESS_TYPE'value into thecommon_lookup_columncolumn when thecommon_lookup_contextcolumn holds a'MULTIPLE'string value. - After these changes, insert two new rows in the
common_lookuptable. They should contain'TELEPHONE'and'TELEPHONE_TYPE'string literal values. One of the rows should contain'HOME'for thecommon_lookup_typecolumn value and the other'WORK'for the same column. - Then, the students were asked to update the foreign key column value in the
telephone_typecolumn of thetelephonetable.
It was a tremendous learning experience for those who did it because there were so many steps required to migrate the structure and data. Years ago, I would offer students half their final grade if they could complete the first four steps in a single UPDATE statement. Occasionally, I had students complete it. We worked through the problem with a small group of students today in one of my two weekly tutoring sessions. I thought it might be nice to document the solution, which use CASE operators in the SET clause of the UPDATE statement.
UPDATE common_lookup
SET common_lookup_table =
CASE
WHEN NOT common_lookup_context = 'MULTIPLE' THEN
common_lookup_context
ELSE
'ADDRESS'
END
, common_lookup_column =
CASE
WHEN common_lookup_table = 'MEMBER' AND
common_lookup_type IN ('VISA_CARD','MASTER_CARD','DISCOVER_CARD') THEN
'CREDIT_CARD_TyPE'
WHEN NOT common_lookup_context = 'MULTIPLE' THEN
CONCAT(common_lookup_context,'_TYPE')
ELSE
'ADDRESS_TYPE'
END;
As a rule, students would solve Step #6 with two UPDATE statements. Very few could see how to create this type of UPDATE statement to migrate from a now obsolete foreign key value to a valid foreign key value:
UPDATE telephone
SET telephone_type =
CASE
WHEN common_lookup_type = 'HOME' THEN
(SELECT common_lookup_id
FROM common_lookup
WHERE common_lookup_table = 'TELEPHONE'
AND common_lookup_type = 'HOME')
ELSE
(SELECT common_lookup_id
FROM common_lookup
WHERE common_lookup_table = 'TELEPHONE'
AND common_lookup_type = 'WORK')
END
WHERE telephone_type =
(SELECT common_lookup_id
FROM common_lookup
WHERE common_lookup_table = 'ADDRESS'
AND common_lookup_type IN ('HOME','WORK');
As always, I hope this helps those looking for new ideas in SQL.

