473,774 Members | 2,182 Online
Bytes | Software Development & Data Engineering Community
+ Post

Home Posts Topics Members FAQ

converting a query with *= into SQL 92

i have a query which goes like this:-

select a.col1,b.col2,c .col2
from tab1 a,tab2 b,tab3 c
where
a.col1 *= b.col1 and
a.col2 *= c.col2 and
b.col3 = c.col3

how do I write this query in SQL 92?

also can we replace *= with =* by interchanging the participating tables as in

"a.col1 *= b.col1" is this same as "b.col1 =* a.col1"
Jul 20 '05 #1
2 2381
One of the problems with the SQL89 join syntax is that different RDBMSs may
execute the query differently when both inner and outer join predicates are
specified. Test the following out to see if it gives the result you expect.

SELECT A.col1, B.col2, C.col2
FROM Tab1 AS A
LEFT JOIN Tab2 AS B
ON A.col1 = B.col1
LEFT JOIN Tab3 AS C
ON A.col2 = C.col2 AND B.col3 = C.col3
also can we replace *= with =* by interchanging the participating tables

as in

If you specify an inner join as well then this might give different results
to your original query. It depends on the order in which the joins are
performed. Use LEFT JOIN / RIGHT JOIN / INNER JOIN instead.

--
David Portas
SQL Server MVP
--
Jul 20 '05 #2
Here is how OUTER JOINs work in SQL-92. Assume you are given:

Table1 Table2
a b a c
====== ======
1 w 1 r
2 x 2 s
3 y 3 t
4 z

and the outer join expression:

Table1
LEFT OUTER JOIN
Table2
ON Table1.a = Table2.a <== join condition
AND Table2.c = 't'; <== single table condition

We call Table1 the "preserved table" and Table2 the "unpreserve d
table" in the query. What I am going to give you is a little
different, but equivalent to the ANSI/ISO standards.

1) We build the CROSS JOIN of the two tables. Scan each row in the
result set.

2) If the predicate tests TRUE for that row, then you keep it. You
also remove all rows derived from it from the CROSS JOIN

3) If the predicate tests FALSE or UNKNOWN for that row, then keep the
columns from the preserved table, convert all the columns from the
unpreserved table to NULLs and remove the duplicates.

So let us execute this by hand:

Let @ = passed the first predicate
Let * = passed the second predicate

Table1 CROSS JOIN Table2
a b a c
=============== ==========
1 w 1 r @
1 w 2 s
1 w 3 t *
2 x 1 r
2 x 2 s @
2 x 3 t *
3 y 1 r
3 y 2 s
3 y 3 t @* <== the TRUE set
4 z 1 r
4 z 2 s
4 z 3 t *

Table1 LEFT OUTER JOIN Table2
a b a c
=============== ==========
3 y 3 t <= only TRUE row
-----------------------
1 w NULL NULL Sets of duplicates
1 w NULL NULL
1 w NULL NULL
-----------------------
2 x NULL NULL
2 x NULL NULL
2 x NULL NULL
3 y NULL NULL <== derived from the TRUE set - Remove
3 y NULL NULL
-----------------------
4 z NULL NULL
4 z NULL NULL
4 z NULL NULL

the final results:

Table1 LEFT OUTER JOIN Table2
a b a c
=============== ==========
1 w NULL NULL
2 x NULL NULL
3 y 3 t
4 z NULL NULL

The basic rule is that every row in the preserved table is represented
in the results in at least one result row.

There are limitations and very serious problems with the extended
equality version of an outer join used in some diseased mutant
products. Consider the two Chris Date tables

Suppliers SupParts
supno supno partno qty
========= ==============
S1 S1 P1 100
S2 S1 P2 250
S3 S2 P1 100
S2 P2 250

and let's do an extended equality outer join like this:

SELECT *
FROM Supplier, SupParts
WHERE Supplier.supno *= SupParts.supno
AND qty < 200;

If I do the outer first, I get:

Suppliers LOJ SupParts
supno supno partno qty
=============== ========
S1 S1 P1 100
S1 S1 P2 250
S2 S2 P1 100
S2 S2 P2 250
S3 NULL NULL NULL

Then I apply the (qty < 200) predicate and get

Suppliers LOJ SupParts
supno supno partno qty
=============== ====
S1 S1 P1 100
S2 S2 P1 100

Doing it in the opposite order

Suppliers LOJ SupParts
supno supno partno qty
=============== ====
S1 S1 P1 100
S2 S2 P1 100
S3 NULL NULL NULL

Sybase does it one way, Oracle does it the other and Centura (nee
Gupta) lets you pick which one -- the worst of both non-standard
worlds! In SQL-92, you have a choice and can force the order of
execution. Either do the predicates after the join ...

SELECT *
FROM Supplier
LEFT OUTER JOIN
SupParts
ON Supplier.supno = SupParts.supno
WHERE qty < 200;

... or do it in the joining:

SELECT *
FROM Supplier
LEFT OUTER JOIN
SupParts
ON Supplier.supno = SupParts.supno
AND qty < 200;

Another problem is that you cannot show the same table as preserved
and unpreserved in the extended equality version, but it is easy in
SQL-92. For example to find the students who have taken Math 101 and
might have taken Math 102:

SELECT C1.student, C1.math, C2.math
FROM (SELECT * FROM Courses WHERE math = 101) AS C1
LEFT OUTER JOIN
(SELECT * FROM Courses WHERE math = 102) AS C2
ON C1.student = C2.student;
Jul 20 '05 #3

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

Similar topics

9
2292
by: wiredog | last post by:
I am struggling rewriting my query from MS Access' IIF, Then to SQL Servers TSQL language. I am hoping some one can give me some guidance. I believe I have the first portion of the query correct but do believe this requires a "NESTED" argument. This is where I am lost. My Original MS ACCESS Query reads-- SELECT DISTINCTROW REGION_TRAFIC.*, IIf(Mid(,5,2)=,
5
2304
by: Terry Bell | last post by:
I'm upsizing an Access database. Got the data converted, working on the front end, converting queries to views, but having trouble converting queries that use logical expressions like the following: SELECT OrderId, Sum((BackOrderQtyAvailable>0)*-1) AS ReadyBackOrderItems FROM OrderDetails INNER JOIN Items ON (OrderDetails.ClientId = Items.ClientId) AND (OrderDetails.ItemId = Items.ItemId) WHERE (NOT (SitesCustomerTypeId = 2
4
2026
by: dschl | last post by:
Hi, I'm converting an Access 2000 database to Sql Server and must be missing something obvious. Using the Import utility in Sql Server, the Access queries seem to get executed and the resultant data imported as tables. Oops! Using the Upsize lizard in Access 2003, the queries aren't even in the selection list of "tables" to upsize. It looks like the Upsize wizard
2
4092
by: Thomas Bean | last post by:
Hello, I'm fairly new to DB2. I am having some difficulty converting some stored procedres from Informix that use default input parameters. Specifically, the Informix procedures I need to convert use the '*' character as a default input parameter to be used with the 'MATCHES' condition if the input value is null. For example: CREATE PROCEDURE "informix".stored_proc(input1 DECIMAL(18,8), input2 CHAR(20) DEFAULT '*')
8
5107
by: Venkata C | last post by:
Hi! Does anyone here know of a way to goad DB2 into converting a correlated subquery to a non-correlated one? Does DB2 ever do such a conversion? We have a query of the form SELECT .. FROM A WHERE EXISTS (SELECT 'X' FROM B, C WHERE B.COL1 = A.COL1 AND B.COL2 = A.COL2
2
1965
by: John Ortt | last post by:
Hi All, I have a database in Access 97 which works fine but our company is converting from NT4 to XP Pro and in the process changing Office 97 for Office 2003. I have tried to convert the 97 database into Access 2003 but the Autoexec macro falls over on the query below. I have tried running it separayely and the computer just hangs. I realise there is a lot of code below, but I'm hoping somebody may know what they are looking for...
7
5384
by: hasanainf | last post by:
Hi all, I have two querys QueryPurchased ProductID Location TotPcs Prod1 Loc1 100 Prod2 Loc1 50 Prod3 Loc1 150 Prod3 Loc3 150
59
7521
by: Rico | last post by:
Hello, I have an application that I'm converting to Access 2003 and SQL Server 2005 Express. The application uses extensive use of DAO and the SEEK method on indexes. I'm having an issue when the recordset opens a table. When I write Set rst = db.OpenRecordset("MyTable",dbOpenTable, dbReadOnly) I get an error. I believe it's invalid operation or invalid parameter, I'm
12
2618
by: dav3 | last post by:
Hi again folks. I have a function called "linearRegression()" now I am along way from finishing this function atm. A little about this function: The function executes an SQL query grabbing a column from a table in my database called "Yahoo". Now here is where things are getting fuzzy for me. I need to be able to perform mathematical operations on this result set ie. finding the rsquared value, slope, average etc..... but i cannot do any of this...
10
3812
by: Anthony97 | last post by:
This is a problem I've been fighting through for the last month. I've been tasked with converting access 2007 queries to SQL Server 2005. I have been able to convert a number of queries associated with one data base now I'm running into problems with IIf. I've looked at the books online and tried to debug the query I'm working on now. This query will be a model for other queries moving forward. Has anyone had success working with IIf and...
0
9621
marktang
by: marktang | last post by:
ONU (Optical Network Unit) is one of the key components for providing high-speed Internet services. Its primary function is to act as an endpoint device located at the user's premises. However, people are often confused as to whether an ONU can Work As a Router. In this blog post, we’ll explore What is ONU, What Is Router, ONU & Router’s main usage, and What is the difference between ONU and Router. Let’s take a closer look ! Part I. Meaning of...
0
9454
by: Hystou | last post by:
Most computers default to English, but sometimes we require a different language, especially when relocating. Forgot to request a specific language before your computer shipped? No problem! You can effortlessly switch the default language on Windows 10 without reinstalling. I'll walk you through it. First, let's disable language synchronization. With a Microsoft account, language settings sync across devices. To prevent any complications,...
1
10040
by: Hystou | last post by:
Overview: Windows 11 and 10 have less user interface control over operating system update behaviour than previous versions of Windows. In Windows 11 and 10, there is no way to turn off the Windows Update option using the Control Panel or Settings app; it automatically checks for updates and installs any it finds, whether you like it or not. For most users, this new feature is actually very convenient. If you want to control the update process,...
0
9914
tracyyun
by: tracyyun | last post by:
Dear forum friends, With the development of smart home technology, a variety of wireless communication protocols have appeared on the market, such as Zigbee, Z-Wave, Wi-Fi, Bluetooth, etc. Each protocol has its own unique characteristics and advantages, but as a user who is planning to build a smart home system, I am a bit confused by the choice of these technologies. I'm particularly interested in Zigbee because I've heard it does some...
0
8939
agi2029
by: agi2029 | last post by:
Let's talk about the concept of autonomous AI software engineers and no-code agents. These AIs are designed to manage the entire lifecycle of a software development project—planning, coding, testing, and deployment—without human intervention. Imagine an AI that can take a project description, break it down, write the code, debug it, and then launch it, all on its own.... Now, this would greatly impact the work of software developers. The idea...
0
5484
by: adsilva | last post by:
A Windows Forms form does not have the event Unload, like VB6. What one acts like?
1
4012
by: 6302768590 | last post by:
Hai team i want code for transfer the data from one system to another through IP address by using C# our system has to for every 5mins then we have to update the data what the data is updated we have to send another system
2
3611
muto222
by: muto222 | last post by:
How can i add a mobile payment intergratation into php mysql website.
3
2852
bsmnconsultancy
by: bsmnconsultancy | last post by:
In today's digital era, a well-designed website is crucial for businesses looking to succeed. Whether you're a small business owner or a large corporation in Toronto, having a strong online presence can significantly impact your brand's success. BSMN Consultancy, a leader in Website Development in Toronto offers valuable insights into creating effective websites that not only look great but also perform exceptionally well. In this comprehensive...

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.