473,811 Members | 1,788 Online
Bytes | Software Development & Data Engineering Community
+ Post

Home Posts Topics Members FAQ

case, joins and NULL trouble

Hi

Consider two tables
id1 code1
----------- -----
1 a
2 b
3 c

id2 code2 value
----------- ----- -----------
1 a 0
2 a 1
3 b 1

They are joined on the code field.

For each code, I want the maximum corresponding value. If the value
doesn't exist (corresponding code in second table doesn't exist), I want
a NULL field returned.

The result should look like this:
code2 value
----- -----------
a 1
b 1
c NULL

I can't get it to include the NULL row.
While there are uniqe ID's in this example, the real life example uses a
horrible four field compound key.
Any help would be appreciated.

Ger.

The above example can be recreated by the following script.

DROP table #temp1
DROP table #temp2

SELECT 1 AS 'id1', 'a' AS 'code1'
INTO #temp1
UNION
SELECT 2, 'b'
UNION
SELECT 3, 'c'

SELECT 1 AS 'id2', 'a' AS 'code2', 0 AS value
INTO #temp2
UNION
SELECT 2, 'a', 1
UNION
SELECT 3, 'b', 1

SELECT code2, value
FROM #temp1 t1
LEFT JOIN #temp2 t2 ON t1.code1 = t2.code2
WHERE CASE
WHEN t2.value IS NULL THEN 1
WHEN t2.value = 0 THEN 2
WHEN t2.value = 1 THEN 3
END = (
SELECT
MAX( CASE
WHEN value IS NULL THEN 1
WHEN value = 0 THEN 2
WHEN value = 1 THEN 3
END )
FROM
#temp2
WHERE
code2 = t2.code2
)

Jul 23 '05 #1
5 1765
Hi

You may want to try something like:

SELECT t1.code1 as Code2, (SELECT MAX(value) FROM T2 WHERE T2.code2 =
t1.code1 ) AS Value
FROM T1

John

"Geremy" <v@x.com> wrote in message
news:MP******** *************** *@freenews.iine t.net.au...
Hi

Consider two tables
id1 code1
----------- -----
1 a
2 b
3 c

id2 code2 value
----------- ----- -----------
1 a 0
2 a 1
3 b 1

They are joined on the code field.

For each code, I want the maximum corresponding value. If the value
doesn't exist (corresponding code in second table doesn't exist), I want
a NULL field returned.

The result should look like this:
code2 value
----- -----------
a 1
b 1
c NULL

I can't get it to include the NULL row.
While there are uniqe ID's in this example, the real life example uses a
horrible four field compound key.
Any help would be appreciated.

Ger.

The above example can be recreated by the following script.

DROP table #temp1
DROP table #temp2

SELECT 1 AS 'id1', 'a' AS 'code1'
INTO #temp1
UNION
SELECT 2, 'b'
UNION
SELECT 3, 'c'

SELECT 1 AS 'id2', 'a' AS 'code2', 0 AS value
INTO #temp2
UNION
SELECT 2, 'a', 1
UNION
SELECT 3, 'b', 1

SELECT code2, value
FROM #temp1 t1
LEFT JOIN #temp2 t2 ON t1.code1 = t2.code2
WHERE CASE
WHEN t2.value IS NULL THEN 1
WHEN t2.value = 0 THEN 2
WHEN t2.value = 1 THEN 3
END = (
SELECT
MAX( CASE
WHEN value IS NULL THEN 1
WHEN value = 0 THEN 2
WHEN value = 1 THEN 3
END )
FROM
#temp2
WHERE
code2 = t2.code2
)

Jul 23 '05 #2
Geremy (v@x.com) writes:
SELECT code2, value
FROM #temp1 t1
LEFT JOIN #temp2 t2 ON t1.code1 = t2.code2
WHERE CASE
WHEN t2.value IS NULL THEN 1
WHEN t2.value = 0 THEN 2
WHEN t2.value = 1 THEN 3
END = (
SELECT
MAX( CASE
WHEN value IS NULL THEN 1
WHEN value = 0 THEN 2
WHEN value = 1 THEN 3
END )
FROM
#temp2
WHERE
code2 = t2.code2
)


There is a "classical" error here. And don't feel ashamed, it took me
some time, before I learnt the subtle difference between WHERE and
ON.

When you say "t1 LEFT JOIN t2 ON ... ", you tell SQL Server to take
all rows in t1, and the matching rows in t2. For the rows in t1 where
is no match in t1, the columns from t2 are NULL.

This resulting table is then used as input to the next JOIN clause.
(Conceptually, that is, the optimizer may evaluate the query in
different order.) Finally, the WHERE clause is applied as a filter
on the resulting table. This means that for this non-matching rows
t2.code2 will be NULL on the next-to-last line.

If you would change WHERE to AND (and code2 to code in the SELECT
list), the query would give the correct result, because the subquery
would be resolved earlier.

However, this is a much simpler version of the query:

SELECT t1.code1, t2.value
FROM #temp1 t1
LEFT JOIN (SELECT code2, value = MAX(value)
FROM #temp2
GROUP BY code2) AS t2 ON t1.code1 = t2.code2

I am here using a derived table which conceptually is a derived
query within the subquery. Again, conceptually only. The optimizer
may recast computation order. In fact, my experience is that a solution
like this one performs a lot better than the correlated subquery
that John suggested.
--
Erland Sommarskog, SQL Server MVP, es****@sommarsk og.se

Books Online for SQL Server SP3 at
http://www.microsoft.com/sql/techinf...2000/books.asp
Jul 23 '05 #3
I cannot bring myself to use that proprietary temp table syntax and
lose a primary key.

DROP TABLE Foobar1, Foobar2;

CREATE TABLE Foobar1
(t_id INTEGER NOT NULL PRIMARY KEY, code1 CHAR(1) NOT NULL);
INSERT INTO Foobar1 VALUES (1, 'a');
INSERT INTO Foobar1 VALUES (2, 'b');
INSERT INTO Foobar1 VALUES (3, 'c');

CREATE TABLE Foobar2
(t_id INTEGER NOT NULL PRIMARY KEY, code2 CHAR(1) NOT NULL, value
INTEGER NOT NULL);
INSERT INTO Foobar2 VALUES (1, 'a', 0);
INSERT INTO Foobar2 VALUES (2, 'a', 1);
INSERT INTO Foobar2 VALUES (3, 'b', 1);

If you did not need the NULLs, this would do it:

SELECT T2.code2, MAX(T2.value)
FROM Foobar2 AS T2
WHERE EXISTS
(SELECT *
FROM Foobar1 AS T1
WHERE T1.code1 = T2.code2)
GROUP BY T2.code2;

With the NULLs, use this;

SELECT T1.code1, MAX(T2.value)
FROM Foobar1 AS T1
LEFT OUTER JOIN
Foobar2 AS T2
ON T1.code1 = T2.code2
GROUP BY T1.code1;

This should be faster than correlated subqueries.

Jul 23 '05 #4
es****@sommarsk og.se says...
Geremy (v@x.com) writes:
SELECT code2, value
FROM #temp1 t1
LEFT JOIN #temp2 t2 ON t1.code1 = t2.code2
WHERE CASE
WHEN t2.value IS NULL THEN 1
WHEN t2.value = 0 THEN 2
WHEN t2.value = 1 THEN 3
END = (
SELECT
MAX( CASE
WHEN value IS NULL THEN 1
WHEN value = 0 THEN 2
WHEN value = 1 THEN 3
END )
FROM
#temp2
WHERE
code2 = t2.code2
)


There is a "classical" error here. And don't feel ashamed, it took me
some time, before I learnt the subtle difference between WHERE and
ON.

When you say "t1 LEFT JOIN t2 ON ... ", you tell SQL Server to take
all rows in t1, and the matching rows in t2. For the rows in t1 where
is no match in t1, the columns from t2 are NULL.

This resulting table is then used as input to the next JOIN clause.
(Conceptually, that is, the optimizer may evaluate the query in
different order.) Finally, the WHERE clause is applied as a filter
on the resulting table. This means that for this non-matching rows
t2.code2 will be NULL on the next-to-last line.

If you would change WHERE to AND (and code2 to code in the SELECT
list), the query would give the correct result, because the subquery
would be resolved earlier.

However, this is a much simpler version of the query:

SELECT t1.code1, t2.value
FROM #temp1 t1
LEFT JOIN (SELECT code2, value = MAX(value)
FROM #temp2
GROUP BY code2) AS t2 ON t1.code1 = t2.code2

I am here using a derived table which conceptually is a derived
query within the subquery. Again, conceptually only. The optimizer
may recast computation order. In fact, my experience is that a solution


Cheers mate, if I could kiss you I would. Thanks not only for the
solution, but also for a fantastic explanation. I've learned something
today.

There's a cold pint waiting for you in Australia if you ever make it
down here.

Thanks again.
Ger
Jul 23 '05 #5
In article <11************ **********@o13g 2000cwo.googleg roups.com>,
jc*******@earth link.net says...
I cannot bring myself to use that proprietary temp table syntax and
lose a primary key.

DROP TABLE Foobar1, Foobar2;

CREATE TABLE Foobar1
(t_id INTEGER NOT NULL PRIMARY KEY, code1 CHAR(1) NOT NULL);
INSERT INTO Foobar1 VALUES (1, 'a');
INSERT INTO Foobar1 VALUES (2, 'b');
INSERT INTO Foobar1 VALUES (3, 'c');

CREATE TABLE Foobar2
(t_id INTEGER NOT NULL PRIMARY KEY, code2 CHAR(1) NOT NULL, value
INTEGER NOT NULL);
INSERT INTO Foobar2 VALUES (1, 'a', 0);
INSERT INTO Foobar2 VALUES (2, 'a', 1);
INSERT INTO Foobar2 VALUES (3, 'b', 1);

If you did not need the NULLs, this would do it:

SELECT T2.code2, MAX(T2.value)
FROM Foobar2 AS T2
WHERE EXISTS
(SELECT *
FROM Foobar1 AS T1
WHERE T1.code1 = T2.code2)
GROUP BY T2.code2;

With the NULLs, use this;

SELECT T1.code1, MAX(T2.value)
FROM Foobar1 AS T1
LEFT OUTER JOIN
Foobar2 AS T2
ON T1.code1 = T2.code2
GROUP BY T1.code1;

This should be faster than correlated subqueries.

Thanks for your reply, while I didn't use it, I do appreciate the time
spent to answer, and the solution is now in the archived for anyone to
try.

Ger
Jul 23 '05 #6

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

Similar topics

6
2088
by: jgalzic | last post by:
Hi, I'm having trouble doing joins correctly on two tables. I've read up a lot about the different types of joins and tried lots of variations on inner, outer, and left joins with no avail. Something isn't correct with my logic so could anyone give me some pointers on it? I have 2 tables: CourseRoster: ID CourseID StudentID StudentType
3
6421
by: Prem | last post by:
Hi, I am having many problems with inner join. my first problem is : 1) I want to know the precedance while evaluating query with multiple joins. eg. select Employees.FirstName, Employees.LastName, TerritoryID, Employees.EmployeeID, RegionID, ProductID from Employees
4
1914
by: Bung | last post by:
Hi, I have a tricky sql statment I have to write (tricky for me) and I am stuck. I'm having trouble with the following problem. Table1 (Column a, Column b, Column c) Table2 (Column a, Column b, Column c) Table3 (Column a, Column b, Column c) Table1 contains a row of value (1, 2, 3)
1
2797
by: nuked | last post by:
I have a table that has values of variables for certain entities. The columns of interest are targetID, variableID, and valueID. A row (1, 5, 9) means that target number 1 has a value of 9 for variable 5. Being denormalized, target number one will have many possible rows in this table, one for each variable for which it has a value. My problem occurs when I want to find out what targets match a certain set of variable values. For...
4
1428
by: Scott Marquardt | last post by:
My SQL acumen stems from just a couple courses, and everything since from the trenches. Fun + angst over time. I'm needing some advice on joins. Though I understand the basics, I'm having problems abstracting from instances where it's easy to think about discrete key values (. . . and studentid = 1234) to entire sets of users, with the joins doing their work. For example, currently I'm going nuts trying to return dates for which...
1
1420
by: oneannoyingguy | last post by:
I am having some trouble reaching my intended results in combining information from a few tables. The easiest way to explain is with a dummy model t1________________________ date - portfolio - group - contn ====================== d1 A a 5 d1 A b 6 d1 A c 7 d2 A b 9 d2 A c 10
0
18517
NeoPa
by: NeoPa | last post by:
Introduction Joins, in SQL, are a way of linking Recordsets together. They involve restricting which data is returned in the output Recordset. When no join is specified but two Recordsets are, then a cartesian product is produced which specifies no restrictions. Conceptually, a JOIN is applied before any WHERE clause which may be specified. NB. Full Outer Joins are not supported in Access (Jet) SQL. When Recordsets are JOINed they...
2
3178
by: beargrease | last post by:
I'm kind of comfortable with basic joins, but a current project requires a complex query of many tables. The GROUP_CONCAT(DISTINCT ...) function has been very useful as returning my values as comma delimited values when joining multiple tables. I have one table called 'floorplans' which has two fields (floorplan_jpg & floorplan_pdf), I'd like each of these fields to return arrays of the same length (they have the same # of values in the data...
2
1836
pradeepjain
by: pradeepjain | last post by:
I have 2 tables like desc product_subcategory; +----------------+--------------+------+-----+---------+----------------+ | Field | Type | Null | Key | Default | Extra | +----------------+--------------+------+-----+---------+----------------+ | product_id | int(11) | NO | PRI | NULL | auto_increment | | product_name | varchar(200) | NO | | NULL | | | subcategory_id |...
0
9728
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
9605
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
10402
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
10135
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...
1
7670
isladogs
by: isladogs | last post by:
The next Access Europe User Group meeting will be on Wednesday 1 May 2024 starting at 18:00 UK time (6PM UTC+1) and finishing by 19:30 (7.30PM). In this session, we are pleased to welcome a new presenter, Adolph Dupré who will be discussing some powerful techniques for using class modules. He will explain when you may want to use classes instead of User Defined Types (UDT). For example, to manage the data in unbound forms. Adolph will...
0
5554
by: TSSRALBI | last post by:
Hello I'm a network technician in training and I need your help. I am currently learning how to create and manage the different types of VPNs and I have a question about LAN-to-LAN VPNs. The last exercise I practiced was to create a LAN-to-LAN VPN between two Pfsense firewalls, by using IPSEC protocols. I succeeded, with both firewalls in the same network. But I'm wondering if it's possible to do the same thing, with 2 Pfsense firewalls...
0
5692
by: adsilva | last post by:
A Windows Forms form does not have the event Unload, like VB6. What one acts like?
1
4339
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
3867
muto222
by: muto222 | last post by:
How can i add a mobile payment intergratation into php mysql website.

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.