Archive for September, 2015

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

People aren’t people: when matching them can be hard

I’m going to spend a few posts on a subject that is, frankly, the bane of my life: people matching. That is, given two sets of person-related details, do I believe they are the same person? It’s eminently useful for many things including keeping marketing costs down, improving customer service, and very importantly, preventing fraud.

If your dataset(s) contain a unique person key, e.g. Social Security Number in the USA, or National Insurance Number here in the UK, then the task is obviously pretty simple (barring errors in the data). If there’s no unique person key, you’ve got a great deal more work to do. I’d say it follows a 95 / 5 rule: to match the first 95% of your dataset takes 5% of the time, the 5% that’s left takes the remaining 95% of the time. (Hence why it causes me grief: you can end up writing reams of code to match a handful of details, in a never-ending quest for greater accuracy!)

Before I start discussing how I’d do people matching in a “perfect world” scenario, I’m going to list some of the problems I’ve encountered when trying to match data from UK sources.

Names

  • Shortened or alternative forms of the first name: e.g. Bill / William, Peggy / Margaret, Jack / John. And these days, Alfie probably isn’t short for Alfred, just as Harry probably isn’t short for Harold (or even a boy’s name).
  • As per the above, I wouldn’t ever assume a particular first name implies a gender; you’ll be wrong at some point, and an awkward conversation might ensue.
  • Using middle names as first names; famous examples include Hannah Dakota Fanning, William Bradley Pitt, Walter Bruce Willis, James Paul McCartney, Laura Jeanne Reese Witherspoon.
  • Married names, people taking their spouse’s last name, without any restrictions on gender.
  • Double-barrelling last names with spouse or partner.
  • Very common names – names like ‘George Smith’ and ‘Claire Wilson’ mean placing more reliance on other pieces of information when matching.

Titles

  • In my experience, Mr/Ms/Miss/Mrs etc. are rarely correct enough to rely on to indicate gender or married status*, even when the primary source is data the customer has entered themselves. Also, the gender-neutral Mx is becoming increasingly common.
  • Let’s not even get into the realms of Professor, Doctor, Lord/Lady, Reverend and assorted military titles…

* Using gender and married status purely as aids to matching people, nothing else.

Dates of birth

It’s very easy to get the date of birth wrong with mis-typing, or getting the month and day the wrong way round. Also, people (a) don’t like to give their birthdate out, so may give a dummy one (1st Jan 1970 is common), or (b) will lie about their age if they think it improves their chances of obtaining a product or service.

People with “non-traditionally British” names

  • People from other countries adopting a Western-style first name alongside their traditional birth-name (e.g. Chinese people).
  • First names / family names may not be in the expected order (again, e.g. Chinese).
  • Names that have more than one translation into English, e.g. Mohammed / Muhammad / Mohamed.
  • Different character sets! Greek, Cyrillic, Arabic, etc.

(“Non-traditionally British” is an ugly turn of phrase, there must be a better way of putting it…)

Family

  • Fathers and sons with exactly the same first, middle and last names. (Far more common than you’d think!)
  • Twins; especially twins with very similar first names (Mia/Mya, Ethan/Evan).
  • You can’t reliably infer relationships using only differences in age; two customers from the same family, 32 years apart, could potentially be siblings, parent/child, or even grandparent/grandchild.

Addresses

  • Living at more than one address; in particular, students living away from home.
  • Moving house, sometimes within the same postcode, or even next door.
  • Postcodes not existing yet on the Postcode Address File, although you may find them on Google Maps(!)
  • Postcodes becoming invalid / retired, e.g. postcodes in the districts BS12, BS17-19.
  • Postcodes becoming valid: the district E20 was previously used only for the fictional TV soap Eastenders, but postcodes in this district have now started to be allocated for real addresses.
  • Roads can be renamed [BBC]
  • Buildings can be split into flats.
  • Different naming conventions; flats in Scotland can be named by floor number / flat number, e.g. 2/1 (2nd floor, 1st flat).

Some address-related problems can be solved by using the Unique Property Reference Number (UPRN) or the Unique Delivery Point Reference Number (UDPRN) to represent the address, but neither of these has widespread adoption yet.

Email addresses

  • Having more than one email address.
  • Labels, e.g. fred.smith+SPAM@mailbox.com and fred.smith+NOTSPAM@mailbox.com. The canonical version of the email address would be fred.smith@mailbox.com, which may be more useful for matching purposes.
  • Temporary inboxes, e.g. Mailinator.
  • Format: Validating the syntax of 99% of email addresses is straightforward, getting the full 100% is almost impossible. See here [wikipedia] for a brief explanation about which characters are allowed in an email address.

Mobiles

Home phone numbers

  • Having more than one home phone number.
  • Not having a phone number, but entering one belonging to a friend or relative.
  • Not having a phone number, so using the number of a local taxi firm, public house, or fast-food restaurant (again, more common than you might think).

Bank accounts

  • Having more than one bank account
  • People not moving their bank accounts when they move house. (I live 80 miles away from my nominal branch.)
  • Sort codes changing, especially when banks merge or split.
  • Joint bank accounts
  • Business bank accounts

Debit and credit cards

You almost certainly shouldn’t be storing card details…! [www.theukcardsassociation.org.uk]

Incorrect details

  • Accidental mis-typing
  • Deliberate fraud – typically, the name and address might be real, but the mobile and email will be the fraudster’s.
  • System-testing : internal (dev or UAT environment) vs. external (penetration testing), manual/automated, regular (e.g. employees) / irregular (e.g. competitors testing capabilities; hackers!)
  • Details not existing: some people don’t have home telephone numbers (so put their mobile number in that field instead), whereas other people don’t have mobiles (so they put their home number instead).
  • People just messing around, possibly not-very-maliciously.

Other

  • Older people using younger family members’ email addresses and/or mobile numbers.
  • People who work overseas and have non-UK mobile number and address; they could be a valid customer, as per your policies, but with only non-UK contact details. Do your systems accept a phone number that doesn’t start +44?
  • Driving License / Passport : most existing systems only validate the format of the identifying numbers, which makes them a target for fraudsters. Newer systems can validate images of the documents.
  • Device IDs are great for fraud detection, but can present a problem when matching people; families often share devices, and what about public computers in libraries and internet cafes?
  • Electoral Roll: Being on the full electoral roll at an address is no guarantee that the person is living there, and the converse is also true.

Third-party services exist to validate/verify almost all the information above, singularly and together. However, none of the services are perfect, so matching person-level data comes down to cost (third party data and development time), and your tolerance for mistakes – how embarrassing might it be if you get it wrong?

If you have any examples of when matching personal details has proved trickier than you thought it was going to be, please let me know in the comments below!

, , , , , ,

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