Q
Problem solve Get help with specific problems with your technologies, process and projects.

Another good FULL OUTER JOIN example

I have an OrderTable, with columns OrderDate and Advance, and a SaleTable, with columns SaleDate and Advance. Now I want to show all records from both tables and sum the two advance fields where the dates match.

I have an OrderTable, with columns OrderDate and Advance, and a SaleTable, with columns SaleDate and Advance. Now...

I want to show all records from both tables and sum the two advance fields where the dates match, like this:

 Date OrderAdvance SaleAdvance Total

Thanks.

This question intrigued me because it looked at first like another example of a crosstab. It isn't.

The biggest clue is "show all records from both tables." The second clue is "sum the two advance fields where the dates match." Together, these requirements dictate a FULL OUTER JOIN.

 select OrderTable.OrderDate as theDate , OrderTable.Advance as OrderAdvance , coalesce(SaleTable.Advance,0) as SaleAdvance , OrderTable.Advance +coalesce(SaleTable.Advance,0) as Total from OrderTable left outer join SaleTable on OrderTable.OrderDate = SaleTable.SaleDate union all select SaleTable.SaleDate , 0 , SaleTable.Advance , SaleTable.Advance from OrderTable right outer join SaleTable on OrderTable.OrderDate = SaleTable.SaleDate where OrderTable.OrderDate is null

Note that in the LEFT OUTER JOIN, if there is a row in the OrderTable which has no matching row in the SaleTable, then SaleTable.Advance will by NULL. Therefore we must use COALESCE on that column, since NULLs propagate through expressions, and we don't want Total to be NULL too.

In the RIGHT OUTER JOIN, we retrieve only unmatched rows from the SaleTable (because of the WHERE clause), so we can hardcode the 0s in the SELECT, and set the Total column to SaleTable.Advance.

The above UNION query is the equivalent of a FULL OUTER JOIN. If your database system supports FULL OUTER JOIN syntax, use this query instead:

 select coalesce(OrderTable.OrderDate ,SaleTable.SaleDate) as theDate , coalesce(OrderTable.Advance,0) as OrderAdvance , coalesce(SaleTable.Advance,0) as SaleAdvance , coalesce(OrderTable.Advance,0) +coalesce(SaleTable.Advance,0) as Total from OrderTable full outer join SaleTable on OrderTable.OrderDate = SaleTable.SaleDate

Note the use of COALESCE in the first column. This ensures that a non-null date value will be used in case one or the other is null. Of course, they can't both be null at the same time, can they.

This was last published in October 2005

Dig Deeper on Oracle and SQL

PRO+

Content

Find more PRO+ content and other member only offers, here.

Have a question for an expert?

Please add a title for your question

Get answers from a TechTarget expert on whatever's puzzling you.

You will be able to add details on the next page.

Start the conversation

Send me notifications when other members comment.

By submitting you agree to receive email from TechTarget and its partners. If you reside outside of the United States, you consent to having your personal data transferred to and processed in the United States. Privacy

Please create a username to comment.

-ADS BY GOOGLE

SearchDataManagement

SearchBusinessAnalytics

SearchSAP

SearchSQLServer

TheServerSide

SearchDataCenter

SearchContentManagement

SearchFinancialApplications

Close