Posts Tagged database

Passing structured data to stored procedures

As I wrote about here, I like to pass structured data around using XML (where applicable). While I think it’s the most flexible way, it’s understandable that people might not want to learn XML-parsing syntax, if they don’t have to. Another way of passing data into stored procedures (sprocs) is to use user-defined types (UDTs).

Here’s a simple example:

-- If the UDT already exists, delete it:
IF EXISTS (
	SELECT *
		FROM sys.types
		WHERE is_table_type = 1
		AND [name] = 'ListOfDates'
		AND [schema_id] = SCHEMA_ID('dbo')
	)
BEGIN
	DROP TYPE dbo.ListOfDates
END
GO

-- Create our UDT:
CREATE TYPE dbo.ListOfDates AS TABLE
(
	DateTypeID TINYINT NOT NULL
	,[Date] DATE NOT NULL
)
GO

-- Let's test it out:

SET DATEFORMAT YMD

DECLARE @MyListOfDates AS dbo.ListOfDates

INSERT @MyListOfDates(DateTypeID, [Date])
	VALUES(1, '2016Jan01'),(1, '2016Jan02'),(1, '2016Jan03')
	,(2, '2016Oct10'),(2, '2017Jan01')

SELECT * FROM @MyListOfDates
GO

DateTypeID Date
---------- ----------
1          2016-01-01
1          2016-01-02
1          2016-01-03
2          2016-10-10
2          2017-01-01

Hopefully, that looks straightforward; the way we’ve used it here is not dissimilar to a table variable (e.g. DECLARE @MyTable AS TABLE...), but we can’t pass a table variable to a sproc. We’ll create a test sproc and pass our new user-defined type to it:

-- If the sproc already exists, delete it:
IF OBJECT_ID('dbo.usp_MySproc') IS NOT NULL
BEGIN
	DROP PROCEDURE dbo.usp_MySproc
END
GO

-- Create our sproc:
CREATE PROCEDURE dbo.usp_MySproc
(
	@ListOfDates AS dbo.ListOfDates READONLY
)
AS
BEGIN
	
	SELECT
			DateTypeID
			,MIN([Date]) AS MinDate
			,MAX([Date]) AS MaxDate
		FROM @ListOfDates
		GROUP BY DateTypeID
		ORDER BY DateTypeID

END
GO

-- Test it out:
DECLARE @MyListOfDates AS dbo.ListOfDates
INSERT @MyListOfDates(DateTypeID, [Date])
	VALUES(1, '2016Jan01'),(1, '2016Jan02'),(1, '2016Jan03')
	,(2, '2016Oct10'),(2, '2017Jan01')
	,(3, '2017Feb01'),(3, '2017Feb03'),(3, '2017Feb28')

EXEC dbo.usp_MySproc @ListOfDates = @MyListOfDates
GO

DateTypeID MinDate    MaxDate
---------- ---------- ----------
1          2016-01-01 2016-01-03
2          2016-10-10 2017-01-01
3          2017-02-01 2017-02-28

See the READONLY in the CREATE PROCEDURE? Here’s what happens when you omit it:

The table-valued parameter "@ListOfDates" must be declared with the READONLY option.

This is one of the limitations of user-defined types: they can’t be used to pass data back. So we couldn’t make any changes to @ListOfDates in the sproc, and see those changes reflected outside of the sproc.

There’s another limitation: UDTs can’t be used cross-database. Here’s what happens:

The type name 'MyOtherDatabase.dbo.ListOfDates' contains more than the
maximum number of prefixes. The maximum is 1.

Even if you create the exact same type in another database, with the same name, it won’t work.

(Note that UDTs don’t have to be tables: go here [MSDN] for more info.)


Just for kicks, here’s how I’d replicate the above functionality, but using XML:

-- If the sproc already exists, delete it:
IF OBJECT_ID('dbo.usp_MySproc') IS NOT NULL
BEGIN
	DROP PROCEDURE dbo.usp_MySproc
END
GO

-- Create the sproc:
CREATE PROCEDURE dbo.usp_MySproc
(
	@ListOfDates XML
)
AS
BEGIN
	
	WITH cte_ExtractFromXML AS
	(
		SELECT 
				DateTypeID	= d.i.value('(@type)[1]', 'INT')
				,[Date]		= d.i.value('.[1]', 'DATE')
			FROM @ListOfDates.nodes('//date') d(i)
	)
	SELECT
			DateTypeID
			,MIN([Date]) AS MinDate
			,MAX([Date]) AS MaxDate
		FROM cte_ExtractFromXML
		GROUP BY DateTypeID
		ORDER BY DateTypeID

END
GO

-- Test it with some XML data:
DECLARE @MyListOfDates XML
SET @MyListOfDates = '
<listOfDates>
	<date type="1">2016Jan01</date>
	<date type="1">2016Jan02</date>
	<date type="1">2016Jan03</date>
	<date type="2">2016Oct10</date>
	<date type="2">2017Jan01</date>
	<date type="3">2017Feb01</date>
	<date type="3">2017Feb03</date>
	<date type="3">2017Feb28</date>
</listOfDates>'

EXEC dbo.usp_MySproc @ListOfDates = @MyListOfDates
GO

DateTypeID  MinDate    MaxDate
----------- ---------- ----------
1           2016-01-01 2016-01-03
2           2016-10-10 2017-01-01
3           2017-02-01 2017-02-28

If we wanted to, we could declare our @ListOfDates parameter as OUTPUT, and make changes to it in the sproc, e.g.:

Drop the sproc if it exists:
IF OBJECT_ID('dbo.usp_MySproc') IS NOT NULL
BEGIN
	DROP PROCEDURE dbo.usp_MySproc
END
GO

-- Create our (new and improved) sproc:
CREATE PROCEDURE dbo.usp_MySproc
(
	@ListOfDates XML OUTPUT
)
AS
BEGIN
	
	DECLARE @Aggregated XML

	;WITH cte_ExtractFromXML AS
	(
		SELECT 
				DateTypeID	= d.i.value('(@type)[1]', 'INT')
				,[Date]		= d.i.value('.[1]', 'DATE')
			FROM @ListOfDates.nodes('//date') d(i)
	)
	SELECT @Aggregated = (
		SELECT
				DateTypeID AS '@id'
				,MIN([Date]) AS '@MinDate'
				,MAX([Date]) AS '@MaxDate'
			FROM cte_ExtractFromXML
			GROUP BY DateTypeID
			ORDER BY DateTypeID
			FOR XML PATH('DataType'), ROOT('Aggregated')
	)

	SELECT @ListOfDates = (
		SELECT @ListOfDates, @Aggregated FOR XML PATH('Output'), TYPE
	)

END
GO

-- Run it:
DECLARE @MyListOfDates XML
SET @MyListOfDates = '
<listOfDates>
	<date type="1">2016Jan01</date>
	<date type="1">2016Jan02</date>
	<date type="1">2016Jan03</date>
	<date type="2">2016Oct10</date>
	<date type="2">2017Jan01</date>
	<date type="3">2017Feb01</date>
	<date type="3">2017Feb03</date>
	<date type="3">2017Feb28</date>
</listOfDates>'

EXEC dbo.usp_MySproc @ListOfDates = @MyListOfDates OUTPUT

SELECT @MyListOfDates AS MyListOfDates
GO

<Output>
  <listOfDates>
    <date type="1">2016Jan01</date>
    <date type="1">2016Jan02</date>
    <date type="1">2016Jan03</date>
    <date type="2">2016Oct10</date>
    <date type="2">2017Jan01</date>
    <date type="3">2017Feb01</date>
    <date type="3">2017Feb03</date>
    <date type="3">2017Feb28</date>
  </listOfDates>
  <Aggregated>
    <DataType id="1" MinDate="2016-01-01" MaxDate="2016-01-03" />
    <DataType id="2" MinDate="2016-10-10" MaxDate="2017-01-01" />
    <DataType id="3" MinDate="2017-02-01" MaxDate="2017-02-28" />
  </Aggregated>
</Output>

As you can see, we’ve returned our original list, along with the aggregated data, both under a new parent node.

, , , , ,

Leave a comment

The meaning of NULL, and why magic data is bad

Part 1: NULL

As a junior web developer, I remember other developers warning me about database NULLs: “you don’t really want to deal with them”, “code them out if you can”, “program around them”, “turn them into something else”. Dear reader, they were quite wrong.

For a piece of data, a NULL value can mean any of:

  1. We don’t know this.
  2. We don’t know this yet (but there’s an expectation we’ll know this at a later date).
  3. We don’t know this, because the question of “What is the value of X for object Y?” is not applicable here.
  4. We don’t know this, and the chances of us ever knowing it are practically zero.
  5. It is logically impossible for this data to exist.

Context usually clues us into which meaning of NULL we’re looking at; if a customer’s email address field is NULL, then in terms of the above:

  1. It hasn’t been asked for / provided / collected.
  2. It hasn’t been asked for / provided / collected yet, but we might be getting this data in the future.
  3. The customer doesn’t have an email address.
  4. The rest of the customer’s data is incorrect or missing, so we have no means of contacting them to find their email address.
  5. The ‘customer’ isn’t something capable of owning an email address(*).

Regardless, if a customer doesn’t have an email address in the system, any code that consumes customer data will have to cope in a sensible manner. If the code is a data entry form, then an empty text field will be displayed; but if the code does marketing mail-outs, then it’ll just have to skip that record.

(*) It could be that the table is ‘multi-use’, and the field makes no sense for some types of data.

Going back to meaning (5), a couple of better examples might be:

  • ‘O’ level GCSE results (at age 16):   My age cohort did GCEs, therefore it is logically impossible for anyone to ascertain my GCSE results.
  • Date of last gynaecological exam:   Clearly, this would never be applicable for anyone born genetically male.

(In multivariate analysis, these would be referred to as structural zeros, rather than the usual sampling zeros. “It was impossible for it to occur” vs. “We did not see it occur”.)

Despite NULL being the very embodiment of “no information”, sometimes “no information” is the information in itself! Trivially, e.g., a SQL query to find all customers without email addresses, will specifically look for the NULL value in that field. Data with NULLs in be indexed, same as any other data. You can even create a filtered index that goes straight to the NULL data:

CREATE INDEX IX_Customer_EmailIsNULL
  ON dbo.Customer(Email)
  WHERE Email IS NULL

So a NULL value is generally not something to be avoided, modified, or coded around. It is eminently useful, and a vital part of your data structures.


Part 2: Bad magic

Now, I started with part 1 because of a common pattern I see used in data capture, usually due to novice / junior / misguided developers. An example: I have a database table of addresses (called Address), with the usual fields. My company operates strictly within the UK, so in an effort to keep our data as clean as possible, we have a CHECK constraint on the Postcode field; not a foreign key to a table of all postcodes ever (who wants to maintain that??), but a simple check against the UK postcode format. The check will prevent entries like “unknown”, or mistakes like “SW1A IAA” (‘I’ instead of ‘1’). Also, the postcode is ‘NOT NULL’-able — because every address has a postcode, right?

It might look like this:

CREATE TABLE xyz.[Address]
(
	AddressID INT NOT NULL PRIMARY KEY
	,Line1 VARCHAR(255) NOT NULL
	,Line2 VARCHAR(255) NULL
	,Postcode VARCHAR(10) NOT NULL
		CHECK (Postcode LIKE '[A-Z][0-9] [0-9][A-Z][A-Z]'
		OR Postcode LIKE '[A-Z][A-Z][0-9] [0-9][A-Z][A-Z]')
)

(Clearly the CHECK constraint isn’t exhaustive: as it is, it’ll reject SW1A 1AA, the postcode of Buckingham Palace. It’ll do for illustrating the point.)

If customer data is supplied without a postcode, then any INSERT will fail. What tends to happen, is that over time, you’ll see the Postcode field start to contain values like ZZ1 1ZZ; a value that passes our simple CHECK constraint rules, but is probably not a valid UK postcode.

So how did ZZ1 1ZZ get into the database?

Scenario 1a:

The developer coding the application form tried to INSERT a record with no postcode, thus the operation failed with an error. So in the input form, they put some code to change a blank postcode to ZZ1 1ZZ when INSERT-ing.

Scenario 1b:

The customer input form hooks up to an address validator; if the address cannot be validated, then the customer is asked to fill in all the fields themself, and can easily put in an invalid postcode which doesn’t make it past the simple check constraint on the Address table. The developer dutifully catches the error, changes the postcode to ZZ1 1ZZ and re-INSERTs.

Scenario 2:

A customer complained about being marketed to, and needs to be removed from the database as soon as possible. To do it properly would mean changing code in several systems; the quick hack is to change their postcode to ZZ1 1ZZ, then make sure the mail-out query ignores records with that postcode value. This is then adopted as semi-official practice: “To remove a customer from marketing, just set their postcode to ZZ1 1ZZ.”

There are multiple problems with having a postcode of ZZ1 1ZZ meaning ‘unknown’, ‘error’ or ‘do not contact’:

  1. It’s a ‘magic’ string; for it to have system-wide meaning, every single system must understand it, and what it represents. What if someone INSERT-ed ZZ2 2ZZ? It wouldn’t be similarly understood, it would be treated as a real postcode.
  2. Every new developer and analyst has to be told about the magic string. What if there’s a magic string for every piece of data? Ok, it could be solved by using VIEWs, but then that’s more code that has to be known about, and scrupulously maintained.
  3. What if, by some mistake, post is sent out to that postcode? (This will happen, I guarantee it.) One of your other systems is likely recording the fact that mail has been sent correctly, but the chances of it arriving are slim.
  4. The real postcode ZZ1 1ZZ might not exist now, but it may in the future: there are many examples of postcodes falling into and out of use. How will you know if your postcode is genuine, or a magic string? Take note: postcodes that start ZZ99 are real live NHS “pseudo-postcodes”…

As you’ve probably realised, my answer would be to make the postcode field NULL-able(*), and to INSERT a NULL in the case of missing or broken data, completely avoiding any magic strings. It needs no special handling, and contextually, it very probably has a limited range of well-understood meanings; e.g. if you see a field MiddleName that is NULL for some records, you would presume it to mean the Customer has no middle name.

Note this is why in the email example in Part 1, we shouldn’t use a blank string instead of a NULL – because a blank string is still a ‘magic’ string, just one that would happen to be widely understood. There will be cases when a blank string legitimately means something quite different to a NULL.

(*) I’ve heard people claim that fields with CHECK constraints can’t be NULL-able. In modern flavours of SQL Server, this is demonstrably false. If the field is NULL, the constraint just isn’t checked.


Part 3: Keeping track

By clearing up one locus of ambiguity, I’m afraid I’m going to introduce a new one. Presumably, we’re going to want to record why our postcode field is NULL. We can either:

(A) Create a new lookup table, ReasonForNull (say); add a new field, ReasonForNullID, to our Address table, add a suitable foreign key, and a CHECK constraint that says “if the Postcode is NULL, then ReasonForNullID must not be NULL – and vice versa”, e.g.:

ALTER TABLE xyz.[Address]
ADD CONSTRAINT CK_Address_PostcodeOrReason 
CHECK( (Postcode IS NOT NULL AND ReasonForNullID IS NULL)
	OR (Postcode IS NULL AND ReasonForNullID IS NOT NULL)
)

or

(B) Create our new lookup table (as above), but also create another new table, Address_ReasonForNull, like so:

CREATE TABLE xyz.Address_ReasonForNull
(
	AddressID INT NOT NULL
		CONSTRAINT PK_Address_ReasonForNull
		PRIMARY KEY CLUSTERED
	,ReasonForNullID TINYINT NOT NULL
	,CreatedOn DATETIME NOT NULL
		CONSTRAINT DF_Address_ReasonForNull_CreatedOn
		DEFAULT(GETDATE())
	,CONSTRAINT FK_Address_ReasonForNull_AddressID
		FOREIGN KEY (AddressID)
		REFERENCES xyz.Address(AddressID)
	,CONSTRAINT FK_Address_ReasonForNull_ReasonForNullID
		FOREIGN KEY (ReasonForNullID)
		REFERENCES xyz.ReasonForNull(ReasonForNullID)
)

and only INSERT into it when we have an invalid postcode.

Neither (A) nor (B) is a perfect solution. (A) will waste a byte per Address record (if ReasonForNullID is declared as a TINYINT) if the postcode is ok, but has the advantage of strictly maintaining integrity, thanks to the CHECK constraint. (B) wastes no space, but there is no simple way (that I know of) of enforcing that a child record must exist, given data in the parent record.

If we want to record, say, the postcode that was entered but not validated, then it’s no bother under scenario (B) to add a new field to our Address_ReasonForNull table:

ALTER TABLE xyz.Address_ReasonForNull
	ADD OriginalData VARCHAR(20) NULL

However, if we were doing (A), then we’d have to add this column to the main Address table (and change the CHECK constraint); potentially, we could waste a lot of space.

Personally, I’d favour (B), and would push for all data changes to be made via stored procedures (aka sprocs). That way, I can ensure that the data in my two tables is kept perfectly in sync.

Any thoughts or comments? Feel free to let us know!

, , , ,

Leave a comment

Enforcing type-specific data

“Yeah, yeah, but your scientists were so preoccupied with whether or not they could that they didn’t stop to think if they should.” — Dr Ian Malcolm, Jurassic Park

(Forgive the over-used quote above, but it feels apt — I think you’ll see why.)

In our hypothetical situation, we have two types of Employee: a Manager and an Agent. So to begin with, we have Employee and EmployeeType tables:

CREATE TABLE dbo.EmployeeType
(
  EmployeeTypeID TINYINT NOT NULL
    CONSTRAINT PK_EmployeeType PRIMARY KEY CLUSTERED
  ,[Description] VARCHAR(50) NOT NULL
)
GO
INSERT dbo.EmployeeType(EmployeeTypeID, [Description])
    VALUES(1, 'Agent'), (2, 'Manager')
GO

We’ll say that Agents get a ‘terminal code’ (to access their terminals); Managers don’t need a terminal code, but they do get to use the staff car park, so we’ll need to store their car registration — but only for Managers, Agents aren’t allowed to park at work.

CREATE TABLE dbo.Employee
(
  EmployeeID INT NOT NULL
    CONSTRAINT PK_Employee PRIMARY KEY CLUSTERED
  ,EmployeeTypeID TINYINT NOT NULL 
  ,[Name] VARCHAR(50) NOT NULL
  ,StartDate DATE NOT NULL
  -- 1. Agent-specific
  ,TerminalCode VARCHAR(5) NULL
  -- 2. Manager-specific
  ,CarReg VARCHAR(10) NULL
  ,CONSTRAINT FK_Employee_EmployeeTypeID
    FOREIGN KEY (EmployeeTypeID) REFERENCES dbo.EmployeeType(EmployeeTypeID)
)
GO

Let’s put some data in:

INSERT dbo.Employee
(
  EmployeeID
  ,EmployeeTypeID
  ,[Name]
  ,StartDate
  ,TerminalCode
  ,CarReg
)
  VALUES(1, 1, 'Alan Smith', '2001Jan01', 'AS111', NULL)
    ,(2, 1, 'Brenda Thomson', '2002Feb02', 'BT222', NULL)
    ,(3, 1, 'Colin Underwood', '2003Mar03', 'CU333', NULL)
    ,(4, 2, 'Diana Varney', '2004Apr04', NULL, 'DV65 QAZ')
    ,(5, 2, 'Edward Wilson', '2005May05', NULL, 'EW65 WSX')
GO

So far, so straightforward. Now let’s muck things up:

UPDATE dbo.Employee
  SET CarReg = 'AB91 EDC'
  WHERE EmployeeID = 1
GO

which of course works, but now our mere Agent gets to park for free. (How disastrous!) We can fix this — we’ll put the NULL back in the CarReg field, and add a CHECK constraint to stop it happening again:

UPDATE dbo.Employee
  SET CarReg = NULL
  WHERE EmployeeID = 1
GO

ALTER TABLE dbo.Employee
  ADD CONSTRAINT CK_Employee_CheckFields
    CHECK
      (
      CASE
        WHEN EmployeeTypeID = 1
        THEN CASE WHEN TerminalCode IS NOT NULL AND CarReg IS NULL THEN 1 ELSE 0 END
        WHEN EmployeeTypeID = 2
        THEN CASE WHEN TerminalCode IS NULL AND CarReg IS NOT NULL THEN 1 ELSE 0 END
      END = 1
      )
GO

If we try and set the CarReg for an Agent now, it’ll fail:

The UPDATE statement conflicted with the CHECK constraint "CK_Employee_CheckFields"

Well, that works! Job done, no? Not really… every time we need to add or remove Agent- or Manager-specific fields, we’ll have to change that CHECK constraint; what if there were 100 fields? The constraint could get pretty unwieldy. Not to mention the wasted column space: Agent fields will always be NULL for Managers, and vice versa.

Drop the CHECK constraint, the TerminalCode and CarReg fields in Employee; and then we’ll create two new tables to hold the type-specific data:

CREATE TABLE dbo.AgentData
(
  EmployeeID INT NOT NULL CONSTRAINT PK_AgentData PRIMARY KEY CLUSTERED
  ,TerminalCode VARCHAR(5) NULL
)
GO
INSERT dbo.AgentData(EmployeeID, TerminalCode)
  VALUES(1,  'AS111'), (2, 'BT222'), (3, 'CU333')
GO
CREATE TABLE dbo.ManagerData
(
  EmployeeID INT NOT NULL CONSTRAINT PK_ManagerData PRIMARY KEY CLUSTERED
  ,CarReg VARCHAR(10) NULL
)
GO
INSERT dbo.ManagerData(EmployeeID, CarReg)
  VALUES(4, 'DV65 QAZ'), (5, 'EW65 WSX')
GO

(Foreign keys on EmployeeID removed for clarity.)

That’s better! Except how do we enforce that AgentData only holds EmployeeIDs that relate to Agents, and that ManagerData only holds EmployeeIDs that relate to Managers? We could use a trigger, absolutely. But for the purposes of this post, we have an irrational fear of triggers and don’t want to use them! Can we enforce our rules with just keys?

(And here’s where the quote at the beginning becomes relevant…) Yes, I think we can, but I don’t know that we should. The following solution seems to work, but I don’t know if I’d ever use it in practise, it feels over-the-top. (I should also add, I’ve not tested it in a production-like environment, it might be unsuitable for some reason I’ve not yet discerned.) Anyway, here it is.

Starting from scratch:

CREATE TABLE dbo.Employee
(
  EmployeeID INT NOT NULL
        CONSTRAINT UQ_Employee_EmployeeID UNIQUE
  ,EmployeeTypeID TINYINT NOT NULL 
  ,[Name] VARCHAR(50) NOT NULL
  ,StartDate DATE NOT NULL
  ,CONSTRAINT PK_Employee
        PRIMARY KEY CLUSTERED (EmployeeID, EmployeeTypeID)
  ,CONSTRAINT FK_Employee_EmployeeTypeID
        FOREIGN KEY (EmployeeTypeID) REFERENCES dbo.EmployeeType(EmployeeTypeID)
)

We’ve given the Employee table a composite PRIMARY KEY, comprised of the EmployeeID, and the EmployeeTypeID. The EmployeeID also has a UNIQUE index on it, for two reasons: (1) obviously, to stop the same EmployeeID having multiple types, and (2) so that other tables can reference the EmployeeID in a FOREIGN KEY, without having to include the EmployeeTypeID as well. Without the UNIQUE constraint, we’d get the following error:

There are no primary or candidate keys in the referenced table 'dbo.Employee'
that match the referencing column list in the foreign key

, but with it, we’re ok. We’ll INSERT the same employee details as before:

INSERT dbo.Employee
(
  EmployeeID
  ,EmployeeTypeID
  ,[Name]
  ,StartDate
)
  VALUES(1, 1, 'Alan Smith', '2001Jan01')
    ,(2, 1, 'Brenda Thomson', '2002Feb02')
    ,(3, 1, 'Colin Underwood', '2003Mar03')
    ,(4, 2, 'Diana Varney', '2004Apr04')
    ,(5, 2, 'Edward Wilson', '2005May05')
GO

Here’s a slightly icky bit: we’re going to fix the EmployeeTypeID of 1 in the AgentData table:

CREATE TABLE dbo.AgentData
(
  EmployeeID INT NOT NULL CONSTRAINT PK_AgentData PRIMARY KEY CLUSTERED
  ,EmployeeTypeID AS CAST(1 AS TINYINT) PERSISTED
  ,TerminalCode VARCHAR(5) NULL
  ,CONSTRAINT FK_AgentData_EmployeeID_EmployeeTypeID
    FOREIGN KEY (EmployeeID, EmployeeTypeID) REFERENCES dbo.Employee(EmployeeID, EmployeeTypeID)
)
GO

, and fix the EmployeeTypeID of 2 in the ManagerData table:

CREATE TABLE dbo.ManagerData
(
  EmployeeID INT NOT NULL CONSTRAINT PK_ManagerData PRIMARY KEY CLUSTERED
  ,EmployeeTypeID AS CAST(2 AS TINYINT) PERSISTED
  ,CarReg VARCHAR(10) NULL
  ,CONSTRAINT FK_ManagerData_EmployeeID_EmployeeTypeID
    FOREIGN KEY (EmployeeID, EmployeeTypeID) REFERENCES dbo.Employee(EmployeeID, EmployeeTypeID)
)
GO

Where both tables have a FOREIGN KEY onto the Employee table that includes the EmployeeTypeID, there’s no way to get the types mixed up: an Agent has to be an Agent in both tables, likewise for Managers.

Let’s INSERT the data and check we can query it without any problems:

INSERT dbo.AgentData(EmployeeID, TerminalCode)
  VALUES(1,  'AS111'), (2, 'BT222'), (3, 'CU333')
GO
INSERT dbo.ManagerData(EmployeeID, CarReg)
  VALUES(4, 'DV65 QAZ'), (5, 'EW65 WSX')
GO
SELECT
    e.*
    ,ad.TerminalCode
    ,md.CarReg
  FROM dbo.Employee e
  LEFT JOIN dbo.AgentData ad
    ON ad.EmployeeID = e.EmployeeID
  LEFT JOIN dbo.ManagerData md
    ON md.EmployeeID = e.EmployeeID
  ORDER BY e.EmployeeID
GO
EmployeeID  EmployeeTypeID Name              StartDate  TerminalCode CarReg
----------- -------------- ----------------- ---------- ------------ ----------
1           1              Alan Smith        2001-01-01 AS111        NULL
2           1              Brenda Thomson    2002-02-02 BT222        NULL
3           1              Colin Underwood   2003-03-03 CU333        NULL
4           2              Diana Varney      2004-04-04 NULL         DV65 QAZ
5           2              Edward Wilson     2005-05-05 NULL         EW65 WSX

(5 row(s) affected)

We can also add FOREIGN KEY references from other tables, pointing at the EmployeeIDs on the AgentData and ManagerData tables, and get the expected behaviour, e.g.:

CREATE TABLE dbo.ManagerEmail
(
  EmployeeID INT NOT NULL
    CONSTRAINT PK_ManagerEmail PRIMARY KEY CLUSTERED
  ,EmailAddress VARCHAR(255) NOT NULL
  ,CONSTRAINT FK_ManagerEmail_EmployeeID
    FOREIGN KEY (EmployeeID) REFERENCES dbo.ManagerData(EmployeeID)
)
GO
INSERT dbo.ManagerEmail(EmployeeID, EmailAddress)
	VALUES(4, 'diana.varney@bigcorp.com')
GO
-- works fine, Diana is a Manager

INSERT dbo.ManagerEmail(EmployeeID, EmailAddress)
	VALUES(3, 'colin.underwood@bigcorp.com')
GO
-- Error:
-- "The INSERT statement conflicted with the
-- FOREIGN KEY constraint "FK_ManagerEmail_EmployeeID".

What do you think? Does this work for you, or would a trigger be more straightforward? As always, please let me know in the comments, I’d love to hear from you.

, , , ,

Leave a comment

The Request / Response pattern

Here’s something I come across too often: how do we deal with sending data to and receiving data from external systems? I don’t mean the format of the data, or the transmission mechanism; but simply, how do we keep a record of what occurred? (And I use the word ‘external’ here in a vague sense; it could mean external to your company, external to the current app domain, or just something that you want to keep separate.)

Let’s pretend our system needs to call out to Amazon to query the best price for a book: we send the Amazon service an ISBN, and it returns a number that represents the price.

The Novice Developer (TND) has created a service, underneath which is a table that looks like this:

CREATE TABLE dbo.BookPrice
(
	ISBN CHAR(13) NOT NULL PRIMARY KEY
	,LatestPrice SMALLMONEY NULL
)

(TND probably uses Entity Framework or similar to talk to the database, but I’ll pretend that the usual SQL statements are being used.)

To get a price, the service sends the ISBN to Amazon, gets a response, and INSERTs into the table:

INSERT dbo.BookPrice(ISBN, Price)
	VALUES('9780575082076', 8.99)

, or does an UPDATE if the record already exists. So far, so good. Next time TND runs the service, there’s a problem; the book is out of stock, so Amazon doesn’t return a price. The code does this:

UPDATE dbo.BookPrice
	SET LatestPrice = NULL
	WHERE ISBN = '9780575082076'

An analyst looks at the data, and asks, “Well, why’s that price NULL?”. TND explains, and the analyst points out that there’s no way of telling what a NULL means. It could be any of:

  • The service never attempted to call out to Amazon
  • The service tried to make the call, but there was a network problem
  • The service made the call correctly, but got an error back from Amazon

A manager overhears the conversation, and asks the TND to create a scheduled task that retries calls that didn’t return a price. To facilitate this, the developer changes the table:

ALTER TABLE dbo.BookPrice
	ADD LatestStatus VARCHAR(255) NULL
	, LastOKPrice SMALLMONEY NULL

Now, the UPDATE becomes:

UPDATE dbo.BookPrice 
	SET LatestPrice = NULL
		,LatestStatus = 'Out of stock'
		,LastOKPrice = 8.99
	WHERE ISBN = '9780575082076'

To get the latest price, TND tells the analyst to just run the following query:

SELECT ActualLatestPrice = ISNULL(LatestPrice, LastOKPrice)
	FROM dbo.BookPrice
	WHERE ISBN = '9780575082076'

Sometime later, TND’s service requests the latest price, and the network is down. The service notes this accordingly:

UPDATE dbo.BookPrice
	SET LatestStatus = 'Network problem'
	WHERE ISBN = '9780575082076'

The analyst then points out that the company has SLAs and needs to know if external service calls are failing. TND thinks, and adds a new column:

ALTER TABLE dbo.BookPrice
	ADD NetworkProblemCount INT NULL

and UPDATEs the table again:

UPDATE dbo.BookPrice
	SET NetworkProblemCount = 1
	WHERE ISBN = '9780575082076'

“But we need to know when it happened”, says the analyst. So TND thinks again, and adds another new column:

ALTER TABLE dbo.BookPrice
	ADD LastNetworkProblemDate DATETIME NULL

and UPDATEs the table again:

UPDATE dbo.BookPrice
	SET LastNetworkProblemDate = GETDATE()
	WHERE ISBN = '9780575082076'

Back comes the analyst, “But when was the last time we actually successfully retrieved a price?”, so TND adds another column:

ALTER TABLE dbo.BookPrice
	ADD LastSuccessfulPriceRetrievalDate DATETIME NULL

… and hopefully by this point, you can agree with me that continually adding columns is not the way we should be doing this!

The most straightforward way I know of to record interactions with other systems, is via Request and Response tables. Take a look at the following DDL:

CREATE TABLE dbo.BookPrice_Request
(
	RequestID INT NOT NULL IDENTITY(1,1)
		CONSTRAINT PK_BookPrice_Request PRIMARY KEY CLUSTERED
	,ISBN CHAR(13) NOT NULL
	,CreatedOn DATETIME NOT NULL
		CONSTRAINT DF_BookPrice_Request_CreatedOn DEFAULT(GETDATE())
)

CREATE TABLE dbo.BookPrice_ResponseType
(
	ResponseTypeID TINYINT NOT NULL
		CONSTRAINT PK_BookPrice_ResponseType PRIMARY KEY CLUSTERED
	,[Description] VARCHAR(255) NOT NULL
	,CreatedOn DATETIME NOT NULL
		CONSTRAINT DF_BookPrice_ResponseType_CreatedOn DEFAULT(GETDATE())
)
INSERT dbo.BookPrice_ResponseType(ResponseTypeID, [Description])
	VALUES(10, 'Price obtained successfully')
		, (20, 'Out of stock')
		, (30, 'Network error')

CREATE TABLE dbo.BookPrice_Response
(
	ResponseID INT NOT NULL IDENTITY(1,1)
		CONSTRAINT PK_BookPrice_Response PRIMARY KEY CLUSTERED
	,RequestID INT NOT NULL
	,ResponseTypeID TINYINT NOT NULL
	,Price SMALLMONEY NULL
	,CreatedOn DATETIME NOT NULL
		CONSTRAINT DF_BookPrice_Response_CreatedOn DEFAULT(GETDATE())
	,CONSTRAINT FK_BookPrice_Response_RequestID
		FOREIGN KEY (RequestID)
		REFERENCES dbo.BookPrice_Request(RequestID)
	,CONSTRAINT FK_BookPrice_Response_ResponseTypeID
		FOREIGN KEY (ResponseTypeID)
		REFERENCES dbo.BookPrice_ResponseType(ResponseTypeID)
)

You can run the code above in a test database, and it’ll create three tables: a Request, a Response, and a ResponseType. When our internal service receives a request for a book price, it INSERTs into the Request table. When a reply is received from Amazon, we INSERT into the Response table, with (a) the RequestID we generated earlier, and (b) an indication of what type of response we received.

To recreate what was happening with TND’s service, run the following SQL:


-- Call #1
INSERT dbo.BookPrice_Request(ISBN)
	VALUES('9780575082076')
-- The calling code would get the newly-INSERTed RequestID from SCOPE_IDENTITY()
-- This is the first INSERT into the table, so the returned RequestID will be 1.
-- ... our service gets the response from Amazon...
INSERT dbo.BookPrice_Response(RequestID,ResponseTypeID,Price)
	VALUES(1, 10, 8.99)

-- Call #2
INSERT dbo.BookPrice_Request(ISBN)
	VALUES('9780575082076')
-- the RequestID returned is 2
-- ... our service gets the response 'Out of stock' from Amazon...
INSERT dbo.BookPrice_Response(RequestID,ResponseTypeID,Price)
	VALUES(2, 20, NULL)

-- Call #3
INSERT dbo.BookPrice_Request(ISBN)
	VALUES('9780575082076')
-- the RequestID returned is 3
-- ... our service call fails, there's a problem with the network...
INSERT dbo.BookPrice_Response(RequestID,ResponseTypeID,Price)
	VALUES(3, 30, NULL)

Let’s say a fourth service call was completely successful:


-- Call #4
INSERT dbo.BookPrice_Request(ISBN)
	VALUES('9780575082076')
-- the RequestID returned is 4
-- ... our service gets the response from Amazon...
INSERT dbo.BookPrice_Response(RequestID,ResponseTypeID,Price)
	VALUES(4, 10, 6.99) -- it's on offer at a reduced price

Then to get the latest price for a book (and when that price was obtained), the query is simply:


SELECT
	TOP 1
		rp.Price
		,rp.CreatedOn
	FROM dbo.BookPrice_Response rp
	JOIN dbo.BookPrice_Request rq
		ON rq.RequestID = rp.RequestID
	WHERE rq.ISBN = '9780575082076'
	AND rp.ResponseTypeID = 10
	ORDER BY rp.ResponseID DESC

Our Request and Response tables have a complete record of everything that has happened in our service, and it’s simple for the analyst to build reports around how efficient the service is, and if it’s working correctly.

Before I go, a quick ‘gotcha’ – it’s fresh in my mind because I noticed this in a particular service’s database a few days ago: every Request record had a Response. Now, while that’s certainly the perfect situation, it’s just not realistic; things go wrong. In this case, it turns out that the INSERT into the Request table was only being done at the end of the process, only when a Response had been successfully received. So errors were being returned from the 3rd party system, but the service code was bombing out – therefore we had no visibility of this in the database. It’s very important: the Request and Response have to be written back to the database as soon as they happen, without delay.

, ,

Leave a comment

People are People: matching them anyway

Following on from the previous post, here’s my own recipe for a people-matching system. I don’t go into all the gory technical details – the post would be five times the length – but I hope there’s enough here to get the theme across.

Assumptions

Let’s assume a few things:

  1. We have a large number of Person records (millions?), all from the UK.
  2. We believe that a significant proportion of these records are duplicates or redundant, as they represent the same people; but the details may differ.
  3. We only want to identify the records that match; we’re not looking to build a single all-encompassing representation of a person, wherein data from one record ‘enriches’ another. (More to come on that subject in a future post.)
  4. The quality of data in each Person record varies, maybe markedly; some records may be customers we have a long-standing relationship with, and are very confident of their details. But other records might come from less trusted or unverified sources, e.g. a survey on the website that promises a voucher in return for answering some questions and entering a few personal details; these details would clearly be less reliable.
  5. Our records have the following details (‘data points’):
    • First name
    • Last name
    • Date of birth
    • Address
    • Mobile phone number
    • Email address

    , plus a unique PersonID. We might have other data points available, e.g. home telephone number, employment details, bank account number / sort code, and we could absolutely use them for matching. For now, we’ll concentrate on the six above.

  6. Every Person record only has one set of details, that is, just the six pieces of information that we’ll use for matching. This restriction isn’t that realistic – people can have more than one mobile number or email address, and they move house, and occasionally change their names. Taking this into account in a system doesn’t significantly alter the structure of what’s being proposed here.

Canonical data

For each one of these data points, we want to generate and store what is known as the canonical version: that is, the version that is as standard as we can possibly make it. For names, the simplest thing to do is remove spaces, hyphens and apostrophes, which will help us match “Peter O’Toole” against “Peter Otoole”, or “Andrew Lloyd Webber” against “Andrew Lloyd-Webber”. Dates of birth don’t need changing, as long as they’re being stored in a sensible format (so in SQL we should be using DATE, and not VARCHAR). Phone numbers might be accepted in our system as “+442077319333” or “020 7731 9333”, but we need to translate them into one format – I’d go for the former.

Email addresses: As mentioned in the the previous post, email domains can be synonyms of each other, e.g. gmail.com and googlemail.com. Depending on your data, making domains canonical might be too much effort. Also, with some providers (including gmail) the local part of the address (the left-hand side of the @ symbol) can contain labels, so you’ll need to strip those out to make the canonical version.

Addresses: Making canonical versions of bricks-and-mortar addresses can be the biggest headache, which is why you’ll need an address validator: a piece of software that takes an unformatted address, and turns it into a formatted address. Examples of address validators include PCA Predict (formerly Postcode Anywhere) and Experian Data Quality (formerly QAS). The way they work is that if we present, e.g.

10
SW1A 2AA

or

10 Downing Street
City Of Westminster
LONDON

to the validator, then we’ll get the same result back:

10 Downing Street
LONDON
SW1A 2AA

If you pay for the extra data, then you can get the UDPRN (Unique Delivery Point Reference Number), which maps every postal address into an 8-digit code. If not, you can make your own loose version of it by hashing the text of the validated address, which you can then use for comparing.

From this point on, I’ll assume (a) that all our data points are canonical, and (b) there are no known ‘test’ people within our data – if there are, we should remove them from any matching process.

Excluding common data points

Next, we’ll need to consider generating lists of common and/or dummy data. For example, what are the most popular mobile numbers in the data?

In SQL, our query would look something like this:

SELECT
	TOP 20
		Mobile, COUNT(1) AS Total
	FROM dbo.Person
	WHERE Mobile IS NOT NULL
	GROUP BY Mobile
	HAVING COUNT(1) > 1
	ORDER BY COUNT(1) DESC

If your data comes to you via third parties (e.g. affiliates, introducers, brokers), I should imagine you’ll see something like:

+447000000000
+447777777777
+447123456789
+447111111111
...

with some surprisingly large counts against each. You clearly can’t use these mobile numbers for matching; in fact, you should look at all the associated Person records, to see if it’s worth excluding everyone with obvious dummy numbers like these. But you’ll probably just want to exclude this data point from the match, not exclude the entire Person record.

Similarly, you’ll need to do the same for email addresses, e.g. test@test.com, noone@nothing.com, etc.; and home telephone numbers, if you capture them. (As mentioned previously, when faced with a home telephone number field, some people like to enter phone numbers for their local Chinese restaurants, taxi firms and pubs.)

It’s not as necessary to identify common names and addresses, although you might see a few Joe Bloggs, John Smiths and David Camerons. [Brief aside: it’s always useful to have a table containing the headline details of famous people, so you can stop them getting into your system at the point of entry. It’s unlikely you’ll end up with the Prime Minister’s mobile number or email address in your database – but his name and address are no secret!]

Hard matches

We’re at the point where our data is as standard (canonical) as we can make it, and we have lists (tables) of data points we know we’re NOT going to be matching.

The next step is to ask: Given two sets of details, by what criteria would we confidently say “yes, these two people are the same”? A complete match would be:

First name, Last name, Date of birth, Address*, Mobile, Email, Home phone 

, i.e. every single piece of information – but that’s the most obvious case, and there are certainly subsets of these details that we’d be happy to accept.

(* Address meaning either a UDPRN or a hashed version of the text data returned from the validator.)

If the details of Person A matched those of Person B, for any set of the following details, I’d consider the match to be a hard match:

  • Set 1: First name, Last name, Postcode, Mobile, Email
  • Set 2: First name, Last name, Address, Mobile
  • Set 3: First name, Last name, Address, Email
  • Set 4: Last name, Date of birth, Postcode, Mobile, Email
  • Set 5: First name, Last name, Date of birth, Address
  • Set 6: Date of birth, Address, Mobile
  • Set 7: Date of birth, Address, Email

where Set 1 is the best, and Set 7 the ‘least best’. (You, and your data, of course may disagree.) So, every single piece of information in a set has to be identical between person A and person B for us to consider it a match.

Note that no set of details is a subset of any other; the larger set of details would be redundant.

Remember that, if at all possible, our criteria shouldn’t match the following people:

  • Twins
  • Parents and children with the exact same name
  • Older relatives borrowing mobile numbers and email addresses from other family members

For each Person record, we’ll make (up to) 7 separate hashes, one for each set of details, and store them in a new table. An MD5 hash takes up 16 bytes, so if we had a million records, it’s a maximum of 150MB in space (if we include numeric IDs for the Person and for the set of details).

Finding hard matches between Person records then becomes as simple as finding hashes with more than one PersonID entry in our table – a simple GROUP BY, which if indexed properly, will be lightning quick.

(NB: If we’ve decided that a piece of information in a Person record isn’t suitable for matching, due to being too common or an obvious dummy, then we can’t generate any hashes that include that piece of information; we can’t just put a blank in, the match would be too loose. That’s why it’s “(up to) 7” – not “7” – hashes.)

What next?

What about the rest of our data? We’ve three options:

  1. Do nothing. Depending on our requirements, this might be ok; in the grand scheme of things, what’s a handful of duplicate emails / letters / phone calls?
  2. Manual matching. Again, depending on our situation, this might be perfectly feasible. If there’s any human intervention (for example, a phone call) in our end-to-end process, then it could be straightforward to give your customer-facing employees a screen that says “We’ve found these sets of details that might be the same person, do you agree?”, then let them approve or reject the match.
  3. Scoring. Give various amounts of points to each part of the match criteria, depending on the strength of match between data points. If you like, you can consider this a soft match (cf. the hard matching above).
  4. The second and third options require that you’ve some reason to believe a match might exist in the first place, e.g. an email address or mobile number in common; or a combination of date of birth and postcode. With the right indexes on the data, it’s trivial to generate these candidate lists quickly. (Of course, you don’t need to attempt to match Person records you’ve already matched against each other.)

    Scoring

    The goal is to come up with a scoring mechanism such that likely matches get more ‘points’ than unlikely ones. Outside of some Very Hard Computer Science (probably involving neural networks), I don’t know of any standard ways of generating scorecards where the outcome is unknown – if the outcome is known, then standard methods apply (Google: Building a scorecard.) However, for this particular application, common sense should get us where we want to go.

    For string data like names (first or last), we can make an educated guess at a scoring mechanism, e.g.

    • Full match: 10 points
    • One letter out: 9 points
    • Name A is contained within B (or vice-versa), e.g. “Carter” would match “Knowles-Carter”: 7 points
    • First n letters of A = First n letters of B, where 1 ≤ n ≤ 4: n points
    • Last n letters of A = Last n letters of B, where 2 ≤ n ≤ 5: n-1 points
    • Both names are longer than 5 letters, and have 2 letters incorrect: 2 points

    I don’t know that the above is optimal, but it feels like a good starting point.

    How do we assess how far apart strings are? We need a function that, given two strings, calculates some notion of ‘distance’ between them. Such functions already exist, and the Levenshtein distance (the number of insert/replace edits needed to turn one string into another) is a popular choice.

    For non-string data like dates of birth, we’d start with something like:

    • Full match: 8 points
    • One day out: 7 points
    • Month / day swapped: 6 points
    • One month out: 5 points
    • One year out : 4 points
    • Day and month correct: 3 points

    etc. I’m sure you get the idea: the point is we have lots of options!

    Hence, we build up a scorecard that takes two sets of details and returns a single number, a score. We can apply this scoring function to every pair of details in our candidate list, and generate a score for all matches. Inspecting these matches by eye, it becomes fairly obvious what a good threshold for acceptance would be, and what changes to our scorecard are needed. Within a few iterations, we should have a scorecard and threshold that give us the balance we need between matching correct sets of details (where correctness is assessed by eye, by manually checking a sample), and not matching incorrect sets of details.

    The scorecards can get as complicated as you like: you can award extra points for an uncommon domain in the email addresses, or for having the same post town, or the same home phone number area code; you can subtract points for too many repeated digits in the mobile numbers, or having 1st January as the date of birth, or having a common name (‘John Smith’). The law of diminishing returns applies in spades – you have to determine whether the extra effort is warranted.

    One very important thought: you MUST record exactly how a match between two sets of details was made. Was it a hard match? If so, which one? If the match was via a scorecard, which scorecard was it? (You’ll end up with more than one.) What was the score? What was the threshold that it passed? If you don’t record this information, you can’t hope to reliably improve on the matching process in future.

    Summary

    I’ve not finished on this subject yet, but hopefully this article gives you some ideas about building your own person-matching system, should you require one. I’ve yet to cover:

    1. Generating single person objects from matches
    2. How you practically use such objects within your applications

    I’ll come back to these topics soon.

    As ever, if you’ve any comments, I’d love to hear them!

, ,

Leave a comment

Useless primary keys

It’s very common in the world of website development to have the database built by application developers, rather than a dedicated SQL developer. Indeed, that’s how I started: building portals for traditional media companies, plus the usual B2C and B2B sites. As website developers, we were expected to create our own databases.

One piece of creaky SQL advice that’s often spread around as gospel amongst developers, is that tables require a primary key that’s a single piece of information: usually an incrementing integer, or (shudder) a GUID. Every row has to be able to be uniquely identified by the content of a single column! … But it’s not true. Admittedly, it’s rarely the worst thing wrong with a table, but it is wasteful and quite annoying.

Let’s take a simple enough example, say an HR database that keeps a record of people’s previous job history. We need the Person record (“John Smith”), a Role (“marketing manager”), and an Employer (“IBM”). The bare-bones tables will look something like this:

CREATE TABLE dbo.Person
(
	PersonID INT NOT NULL IDENTITY(1,1) CONSTRAINT PK_Person PRIMARY KEY CLUSTERED
	,FirstName VARCHAR(50) NOT NULL
	,LastName VARCHAR(50) NOT NULL
	,DateOfBirth DATE NOT NULL
)

CREATE TABLE dbo.[Role] -- << I've used square brackets because 'role' is a SQL Server keyword.
(
	RoleID INT NOT NULL IDENTITY(1,1) CONSTRAINT PK_Role PRIMARY KEY CLUSTERED
	,RoleName VARCHAR(100) NOT NULL
)

CREATE TABLE dbo.Employer
(
	EmployerID INT NOT NULL IDENTITY(1,1) CONSTRAINT PK_Employer PRIMARY KEY CLUSTERED
	,EmployerName VARCHAR(100) NOT NULL
)

(I’ve filled the tables with dummy data: 1 million Roles, 1 million Employers, 10 million Person rows)

We now need a way of linking this information together, with some start and end dates. In the back of our mind, we know the most common query is going to involve asking for the records by PersonID.

There are 3 logical options:

Option (1) is the standard developer way of doing it. The table has a clustered integer primary key, every row gets its own number:

CREATE TABLE dbo.PersonEmployment_1
(
	PersonEmploymentID INT NOT NULL IDENTITY(1,1) CONSTRAINT PK_PersonEmployment_1 PRIMARY KEY CLUSTERED
	,PersonID INT NOT NULL
	,EmployerID INT NOT NULL
	,RoleID INT NOT NULL
	,StartDate DATE NOT NULL
	,EndDate DATE NULL
	,CONSTRAINT FK_PersonEmployment_1_PersonID FOREIGN KEY (PersonID) REFERENCES dbo.Person(PersonID)
	,CONSTRAINT FK_PersonEmployment_1_EmployerID FOREIGN KEY (EmployerID) REFERENCES dbo.Employer(EmployerID)
	,CONSTRAINT FK_PersonEmployment_1_RoleID FOREIGN KEY (RoleID) REFERENCES dbo.Role(RoleID)
)

After a couple of weeks of use, we notice it’s running slowly, so some bright spark puts an index on:

CREATE NONCLUSTERED INDEX IX_PersonEmployment_1_PersonID_StartDate ON dbo.PersonEmployment_1(PersonID, StartDate)

But what is that PersonEmploymentID column actually telling us? It’s not meaningful at an application level – you’d never display it to anyone, it’s really only there so the developer is happy that they can find the correct row for UPDATE-ing or DELETE-ing.

Option (2) does away with PersonEmploymentID. For the purposes of our example, a person only has one job at a time, so a better clustering primary key is one formed of the two columns that uniquely identify that slice of employment history: the PersonID and the StartDate.

CREATE TABLE dbo.PersonEmployment_2
(
	PersonID INT NOT NULL
	,EmployerID INT NOT NULL
	,RoleID INT NOT NULL
	,StartDate DATE NOT NULL
	,EndDate DATE NULL
	,CONSTRAINT PK_PersonEmployment_2 PRIMARY KEY CLUSTERED (PersonID, StartDate)
	... (foreign keys, same as before)
)

If we want to UPDATE or DELETE a record, we have to use two pieces of information (PersonID and StartDate) to get the row we need; but that’s ok, it’s a few extra characters of typing in the application.

Option (3) is a hybrid of the two: we genuinely can’t live without our incrementing integer primary key (option 1), but we’ll give in, partially, and make the clustering key from the composite information, same as option (2).

CREATE TABLE dbo.PersonEmployment_3
(
	PersonEmploymentID INT NOT NULL IDENTITY(1,1) CONSTRAINT PK_PersonEmployment_3 PRIMARY KEY NONCLUSTERED
	,PersonID INT NOT NULL
	,EmployerID INT NOT NULL
	,RoleID INT NOT NULL
	,StartDate DATE NOT NULL
	,EndDate DATE NULL
	... (foreign keys, same as before)
)
CREATE UNIQUE CLUSTERED INDEX IXC_PersonEmployment_3 ON dbo.PersonEmployment_3(PersonID, StartDate)

Let’s fill all three tables with the same data: 10 million rows, one job for each Person.

How much disk-space does each option consume?

Option Data size (MB) Index size (MB) Total size (MB)
1 299.336 166.156 465.492
2 261.289 1.180 262.469
3 299.336 166.094 465.430

Options 1 and 3 use basically the same amount; they take up 77% more space than option 2, due to the extra data they use.

Now let’s query the data (with STATISTICS turned on):

SELECT * FROM dbo.PersonEmployment_1 WHERE PersonID = 1234567
SELECT * FROM dbo.PersonEmployment_2 WHERE PersonID = 1234567
SELECT * FROM dbo.PersonEmployment_3 WHERE PersonID = 1234567

Option 1 needs 6 reads, and has to employ a bookmark lookup – that is, the query engine finds the PersonEmploymentID from the index, but has to go back to the main PersonEmployment table to get the rest of the data we asked for. Options 2 and 3 only need 3 reads, and of course no bookmark lookup – because the data is already in the order we need to be able to fulfill our query.

It should be clear by now that the best option for us here is Option 2. It takes up less space, and is quickest for our most common query. In summary, say no to useless primary keys!

, ,

Leave a comment

Help needed: monotonicity without triggers?

I’ve a problem that’s been gnawing away at me for a few days now. It’s easily stated:

Without using triggers, if X and Y are numeric types, can you enforce a rule that says the numerical ordering of column Y must be the same as column X?

That is, ROW_NUMBER() OVER (ORDER BY X) == ROW_NUMBER() OVER (ORDER BY Y). (In mathematical terms, the relationship between X and Y is monotonically increasing.)

E.g.

CREATE TABLE dbo.MyTable
(
	X INT NOT NULL
	,Y INT NOT NULL
)

INSERT dbo.MyTable(X,Y)
	VALUES (1,3), (5,17), (13,54), (17, 65)

, and all is well: order(X) == order(Y) == (1,2,3,4).

But if I then do:

INSERT dbo.MyTable(X,Y)
	VALUES (23, 51)

, the INSERT should fail, as order(Y) == c(1,2,3,5,4) != order(X).

Approaches that do not work:

  • A check constraint that calls a user-defined function. It works on INSERT, but not UPDATE.
  • A view with a UNIQUE index on it. In order to define a UNIQUE index on a view, it must already have a clustered index defined on it. But you can’t create a clustered index on a view that contains LEFT JOINs, or window functions like ROW_NUMBER or LEAD/LAG.

Yes, I can achieve the result I want with a trigger; but for a rule that can be explained so simply, it doesn’t feel right.

Someone somewhere has a beautiful solution to this problem, so if you know of any solution (or indeed, can categorically state that it’s impossible to achieve), please let me know in the comments!

, ,

Leave a comment