473,289 Members | 1,729 Online
Bytes | Software Development & Data Engineering Community
Post Job

Home Posts Topics Members FAQ

Join Bytes to post your question to a community of 473,289 software developers and data experts.

Outer Join syntax

I am now working on SQL Server 2000 having had previous experience on
a different database. Both of the OUTER JOIN syntaxes is different
from what I am used to and I am finding it slightly confusing.

For example, given two tables :

wipm_tbl_mi
wipm_tbl_wi (which may not have data in it for a specific record that
exists in the first table.)

If I use the old style syntax :

SELECT mi.workitemid, wi.datavalue
FROM wipm_tbl_mi mi , wipm_tbl_wi wi
WHERE mi.workitemid *= wi.workitemid
AND mi.workitemid = 1
AND wi.dataname = 'XXX'

I get back

1,NULL

when there is no matching record in wipm_tbl_wi, which is what I
expect.

However, if I try to use the SQL-92 syntax

SELECT mi.workitemid, wi.datavalue
FROM wipm_tbl_mi mi
LEFT OUTER JOIN wipm_tbl_wi wi
ON mi.workitemid = wi.workitemid
WHERE mi.workitemid = 1
AND wi.dataname = 'XXX'

I don't get anything back. Please can someone help me understand what
is wrong with the bottom query.

Thank you,

Martin
Jul 20 '05 #1
2 18083
"Martin" <co*****@hotmail.com> wrote in message
news:ac**************************@posting.google.c om...
I am now working on SQL Server 2000 having had previous experience on
a different database. Both of the OUTER JOIN syntaxes is different
from what I am used to and I am finding it slightly confusing.

For example, given two tables :

wipm_tbl_mi
wipm_tbl_wi (which may not have data in it for a specific record that
exists in the first table.)

If I use the old style syntax :

SELECT mi.workitemid, wi.datavalue
FROM wipm_tbl_mi mi , wipm_tbl_wi wi
WHERE mi.workitemid *= wi.workitemid
AND mi.workitemid = 1
AND wi.dataname = 'XXX'

I get back

1,NULL

when there is no matching record in wipm_tbl_wi, which is what I
expect.

However, if I try to use the SQL-92 syntax

SELECT mi.workitemid, wi.datavalue
FROM wipm_tbl_mi mi
LEFT OUTER JOIN wipm_tbl_wi wi
ON mi.workitemid = wi.workitemid
WHERE mi.workitemid = 1
AND wi.dataname = 'XXX'

I don't get anything back. Please can someone help me understand what
is wrong with the bottom query.

Thank you,

Martin


*= is the obsolete proprietary syntax used for outer joins by SQL Server
prior to version 6.5. OUTER JOIN is the Standard SQL way of doing
outer joins and should always be used. However, it's not simply syntactically
different but semantically different than *=. With outer joins, the join condition
must be evaluated separate from the condition applied to the rows resulting
from the join. The Standard SQL solution allows for this by being able to
specifiy the join condition for the outer join in the FROM clause and
the condition to be applied to the resulting rows of the outer join in the
WHERE clause. The *= syntax at best doesn't make this clear and at
worst won't allow you to specify the result you're looking for since both
kinds of conditions, for the join and the restriction of subsequent rows,
are specified in the WHERE clause.

It's always helpful to provide sample data in the form of INSERT
statements so a proposed solution can be tested, but try

SELECT mi.workitemid, wi.datavalue
FROM wipm_tbl_mi mi
LEFT OUTER JOIN
wipm_tbl_wi wi
ON mi.workitemid = wi.workitemid AND
wi.dataname = 'XXX'
WHERE mi.workitemid = 1

From the LEFT OUTER JOIN condition, every row of mi will be joined to
all rows in wi where mi.workitemid = wi.workitemid and wi.dataname = 'XXX'.
All rows of mi that don't satisfy this condition are joined to a single row
of all NULL values to indicate that there's no matching row from wi.
From the resulting outer join, the WHERE clause only keeps those rows
where mi.workitemid = 1. This will keep rows where wi.dataname is 'XXX'
or NULL, which is your desired result.

Regards,
jag
Jul 20 '05 #2
Thank-you, Jag. Your explanation has helped me understand the general
point, and your suggested SQL has solved my specific problem.

Martin
Jul 20 '05 #3

This thread has been closed and replies have been disabled. Please start a new discussion.

Similar topics

3
by: Phil Powell | last post by:
I'm not kidding, the only reason yesterday you didn't hear from me was because I wasn't coding, but today I am doing something quick, and yes, as always it failed.. right at the SQL statement: ...
3
by: jain-neeraj | last post by:
Hi, We have a problem in our mobile calls billing software. To solve it, I need an outer join in a complicated query. Following are the simplified tables with sample data: create table...
1
by: Rahul Khandpur | last post by:
hi friends, i have one query related to oracle9i outer join condition it is mentioned that we can't use (+) with the operand of OR and IN operators example select...
3
by: mheydman | last post by:
I apologize if this has been asked before- I searched google but could not find a concrete answer. I recently inherited a database whose t-sql code is written in a format that I find difficult...
0
by: Preston Landers | last post by:
Hello all. I am trying to write a query that "just" switches some data around so it is shown in a slightly different format. I am already able to do what I want in Oracle 8i, but I am having...
8
by: Matt | last post by:
Hello I have to tables ar and arb, ar holds articles and a swedish description, arb holds descriptions in other languages. I want to retreive all articles that match a criteria from ar and...
3
by: Martin | last post by:
Hello everybody, I have the following question. As a join clause on Oracle we use " table1.field1 = table2.field1 (+) " On SQL Server we use " table1.field1 *= table2.field1 " Does DB2...
3
by: Doug | last post by:
Hi, I'm more familiar with MSSQL than Access syntax and have run into a problem with correctly putting ( )'s around the joins in a 3 table query. I want to INNER JOIN lenders and accounts and...
0
by: whick | last post by:
Please help me guys. I converted the old outer join syntax (*=) but when i tested the new query the result was different. I want to know what was my mistake. ############ old query...
2
isladogs
by: isladogs | last post by:
The next Access Europe meeting will be on Wednesday 7 Feb 2024 starting at 18:00 UK time (6PM UTC) and finishing at about 19:30 (7.30PM). In this month's session, the creator of the excellent VBE...
0
by: DolphinDB | last post by:
Tired of spending countless mintues downsampling your data? Look no further! In this article, you’ll learn how to efficiently downsample 6.48 billion high-frequency records to 61 million...
0
by: Aftab Ahmad | last post by:
Hello Experts! I have written a code in MS Access for a cmd called "WhatsApp Message" to open WhatsApp using that very code but the problem is that it gives a popup message everytime I clicked on...
0
by: Aftab Ahmad | last post by:
So, I have written a code for a cmd called "Send WhatsApp Message" to open and send WhatsApp messaage. The code is given below. Dim IE As Object Set IE =...
0
isladogs
by: isladogs | last post by:
The next Access Europe meeting will be on Wednesday 6 Mar 2024 starting at 18:00 UK time (6PM UTC) and finishing at about 19:15 (7.15PM). In this month's session, we are pleased to welcome back...
0
by: marcoviolo | last post by:
Dear all, I would like to implement on my worksheet an vlookup dynamic , that consider a change of pivot excel via win32com, from an external excel (without open it) and save the new file into a...
1
isladogs
by: isladogs | last post by:
The next Access Europe meeting will be on Wednesday 6 Mar 2024 starting at 18:00 UK time (6PM UTC) and finishing at about 19:15 (7.15PM). In this month's session, we are pleased to welcome back...
0
by: jfyes | last post by:
As a hardware engineer, after seeing that CEIWEI recently released a new tool for Modbus RTU Over TCP/UDP filtering and monitoring, I actively went to its official website to take a look. It turned...
0
by: ArrayDB | last post by:
The error message I've encountered is; ERROR:root:Error generating model response: exception: access violation writing 0x0000000000005140, which seems to be indicative of an access violation...

By using Bytes.com and it's services, you agree to our Privacy Policy and Terms of Use.

To disable or enable advertisements and analytics tracking please visit the manage ads & tracking page.