Technical Article

An alternative to self-joins

,

Oftentimes there is a need to retrieve different types of the same object (e.g. contacts).  For example, in a Contacts database, you might have a Contact table containing many different types of contacts (employees, customers, suppliers, etc).  Typically, a user might need to see a report of all different types of contacts for an order (e.g., the customer who placed the order, the employee who took the order, etc.).

Most SQL developers use self-joins to accomplish this, as example 1 in the script window demonstrates (note: I am only using a single table for illustration purposes).  Although this does the job, you should know that there is an alternate way to do this (using aggregates and CASE statements) that can often result far fewer scans and better performance, as example 2 below shows.

During my testing while running the graphical showplan,  example 2 only required a Compute Scalar and a Clustered Index Scan (I probably could have gotten even better perormance if my company's database had been indexed better).  Example 1, however, required 6 Merge Join operations and 7 Index Scans.  In addition, example 2 requires far less coding.

While I can't guarantee that this method will result in improved performance in your environment, it's always helpful to now that there is more than one way to perform common programming operations.

/* Example 1: using self joins */
select c.contactid, cl.lastname as client, e.lastname as employee, 
b.lastname as buyer, g.lastname as generic, t.lastname as talent,
sa.lastname as subagent
from contact c
left join contact cl
on c.contactid = cl.contactid
and cl.contacttypeid = 1
left join contact e
on c.contactid = e.contactid
and e.contacttypeid = 2
left join contact b
on c.contactid = b.contactid
and b.contacttypeid = 3
left join contact g
on c.contactid = g.contactid
and g.contacttypeid = 4
left join contact t
on c.contactid = t.contactid
and cl.contacttypeid = 5
left join contact sa
on c.contactid = sa.contactid
and e.contacttypeid = 6

/* Example 2: using aggregates and CASE statements */
select contactid,
max(case contacttypeid when 1 then lastname else null end) as client,
max(case contacttypeid when 2 then lastname else null end) as employee,
max(case contacttypeid when 3 then lastname else null end) as buyer,
max(case contacttypeid when 4 then lastname else null end) as generic,
max(case contacttypeid when 5 then lastname else null end) as talent,
max(case contacttypeid when 6 then lastname else null end) as subagent
from contact
group by contactid

Rate

You rated this post out of 5. Change rating

Share

Share

Rate

You rated this post out of 5. Change rating