Scenario:
You create a report. You have one parameter called ‘CITY’ which contains all valid cities in the state of Florida. This parameter is used to report on all citizens that live in a particular city.
You have two tables.
1) name_table that contains all citizens in Florida.
2) address_table that contains the citizen’s current and previous addresses.
Your report will show the following:
a) Name
b) CURRENT address, city, state, and zipcode
You want to retrieve each citizen’s current address, so you write your SQL like this (Assumming that the address with the greatest entered_date column is the citizen’s current address)
SELECT lastname, firstname, ADDR.address, ADDR.city, ADDR.state, ADDR.zipcode, ADDR.entered_date FROM name_table a LEFT OUTER JOIN (SELECT top 1 address, city, state, zipcode FROM address_table WHERE name_guid = a.name_guid order by entered_date desc) ADDR WHERE ADDR.city IN (@City)
Note: Instead of the typical LEFT OUTER JOIN statement, you need to use a sub select to get the top 1 address (current address) of each citizen based on the entered_date ordered DESC.
Problem?
You can not reference a.name_guid within the sub select of the LEFT OUTER JOIN.
The error you will receive is
“The multi-part identifier “a.name_guid” could not be bound”
Solution?
Use OUTER APPLY instead of LEFT OUTER JOIN
SELECT lastname, firstname, ADDR.address, ADDR.city, ADDR.state, ADDR.zipcode, ADDR.entered_date FROM name_table a OUTER APPLY (SELECT top 1 address, city, state, zipcode FROM address_table WHERE name_guid = a.name_guid order by entered_date desc) ADDR WHERE ADDR.city IN (@City)