472,143 Members | 1,146 Online
Bytes | Software Development & Data Engineering Community
Post +

Home Posts Topics Members FAQ

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

Inner Join Problem

The following query works fine in access and does exactly what I want
it to do however I get a syntax error when I port it over to SQL Server
2000.

-------------

UPDATE OrdersProducts INNER JOIN Products ON OrdersProducts.ProductID =
Products.ProductID SET Products.Stock =
Products.Stock-OrdersProducts.Quantity
WHERE OrdersProducts.OrderID=63116

--------------

Any help would be greatly appreciated

Many thanks

Dec 14 '06 #1
12 3860
Hi,

I feel like my previous post failed... So here is what I was saying...
Just ignore it if my post reappears.;)

----------------------------------------------------------------------------------------------

You can't use the UPDATE statement this way...
Here is the complete definition of its syntax :
UPDATE
{
table_name WITH ( < table_hint_limited [ ...n ] )
| view_name
| rowset_function_limited
}
SET
{ column_name = { expression | DEFAULT | NULL }
| @variable = expression
| @variable = column = expression } [ ,...n ]

{ { [ FROM { < table_source } [ ,...n ] ]

[ WHERE
< search_condition ] }
|
[ WHERE CURRENT OF
{ { [ GLOBAL ] cursor_name } | cursor_variable_name }
] }
[ OPTION ( < query_hint [ ,...n ] ) ]
Thus, in your case, the correct syntax would be :
UPDATE Products
SET Products.Stock = Products.Stock - OrdersProducts.Quantity
FROM
Products
INNER JOIN OrdersProducts ON OrdersProducts.ProductID =
Products.ProductID
WHERE
OrdersProducts.OrderID = 63116

----------------------------------------------------------------------------------------------

Enjoy,

Cédric Del Nibbio
MCP since 2003
MCAD .NET
MCTS SQL Server 2005
in**@bodykind.com a écrit :
The following query works fine in access and does exactly what I want
it to do however I get a syntax error when I port it over to SQL Server
2000.

-------------

UPDATE OrdersProducts INNER JOIN Products ON OrdersProducts.ProductID =
Products.ProductID SET Products.Stock =
Products.Stock-OrdersProducts.Quantity
WHERE OrdersProducts.OrderID=63116

--------------

Any help would be greatly appreciated

Many thanks
Dec 14 '06 #2
Hi,

you may not use the UPDATE statement this way...
UPDATE
{
table_name WITH ( < table_hint_limited [ ...n ] )
| view_name
| rowset_function_limited
}
SET
{ column_name = { expression | DEFAULT | NULL }
| @variable = expression
| @variable = column = expression } [ ,...n ]

{ { [ FROM { < table_source } [ ,...n ] ]

[ WHERE
< search_condition ] }
|
[ WHERE CURRENT OF
{ { [ GLOBAL ] cursor_name } | cursor_variable_name }
] }
[ OPTION ( < query_hint [ ,...n ] ) ]
In your case, the proper syntax would be :
UPDATE Products
SET Products.Stock = Products.Stock - OrdersProducts.Quantity
FROM
Products
INNER JOIN OrdersProducts ON OrdersProducts.ProductID =
Products.ProductID
WHERE
OrdersProducts.OrderID = 63116

Enjoy.

Cédric Del Nibbio
MCP since 2003
MCAD .NET
MCTS SQL Server 2005
in**@bodykind.com a écrit :
The following query works fine in access and does exactly what I want
it to do however I get a syntax error when I port it over to SQL Server
2000.

-------------

UPDATE OrdersProducts INNER JOIN Products ON OrdersProducts.ProductID =
Products.ProductID SET Products.Stock =
Products.Stock-OrdersProducts.Quantity
WHERE OrdersProducts.OrderID=63116

--------------

Any help would be greatly appreciated

Many thanks
Dec 14 '06 #3
The ANSI SQL compliant rewrite of this query would be:

UPDATE Products
SET Stock = (
SELECT Products.Stock - OrdersProducts.Quantity
FROM OrdersProducts
WHERE OrdersProducts.ProductID = Products.ProductID
AND OrdersProducts.OrderID=63116
)
WHERE EXISTS (
SELECT *
FROM OrdersProducts
WHERE OrdersProducts.ProductID = Products.ProductID
AND OrdersProducts.OrderID=63116
)

Since this is standard SQL, it will run on any SQL Server installation,
and should run on any modern RDBMS. It might even run in MS Access.

HTH,
Gert-Jan
"in**@bodykind.com" wrote:
>
The following query works fine in access and does exactly what I want
it to do however I get a syntax error when I port it over to SQL Server
2000.

-------------

UPDATE OrdersProducts INNER JOIN Products ON OrdersProducts.ProductID =
Products.ProductID SET Products.Stock =
Products.Stock-OrdersProducts.Quantity
WHERE OrdersProducts.OrderID=63116

--------------

Any help would be greatly appreciated

Many thanks
Dec 14 '06 #4
The following query appears to work correctly in SQL server, the only
problem (and it is a major problem) is that it sets the value of the
stock field to null on every record except the one that it is reducing.

Any ideas?

----------------------------------------------------------------------------------------------------
UPDATE Products

SET Products.Stock = Products.Stock -

(
select sum(OrdersProducts.Quantity)
from OrdersProducts
where ordersproducts.ProductID=products.ProductID and
ordersproducts.orderid = 63116 group by ordersproducts.ProductID
)

FROM Products

----------------------------------------------------------------------------------------------------
Gert-Jan Strik wrote:
The ANSI SQL compliant rewrite of this query would be:

UPDATE Products
SET Stock = (
SELECT Products.Stock - OrdersProducts.Quantity
FROM OrdersProducts
WHERE OrdersProducts.ProductID = Products.ProductID
AND OrdersProducts.OrderID=63116
)
WHERE EXISTS (
SELECT *
FROM OrdersProducts
WHERE OrdersProducts.ProductID = Products.ProductID
AND OrdersProducts.OrderID=63116
)

Since this is standard SQL, it will run on any SQL Server installation,
and should run on any modern RDBMS. It might even run in MS Access.

HTH,
Gert-Jan
"in**@bodykind.com" wrote:

The following query works fine in access and does exactly what I want
it to do however I get a syntax error when I port it over to SQL Server
2000.

-------------

UPDATE OrdersProducts INNER JOIN Products ON OrdersProducts.ProductID =
Products.ProductID SET Products.Stock =
Products.Stock-OrdersProducts.Quantity
WHERE OrdersProducts.OrderID=63116

--------------

Any help would be greatly appreciated

Many thanks
Dec 17 '06 #5
in**@bodykind.com wrote:
The following query appears to work correctly in SQL server, the only
problem (and it is a major problem) is that it sets the value of the
stock field to null on every record except the one that it is reducing.

Any ideas?

----------------------------------------------------------------------------------------------------
Did you try the query that Gert-Jan posted?

--
David Portas, SQL Server MVP

Whenever possible please post enough code to reproduce your problem.
Including CREATE TABLE and INSERT statements usually helps.
State what version of SQL Server you are using and specify the content
of any error messages.

SQL Server Books Online:
http://msdn2.microsoft.com/library/m...S,SQL.90).aspx
--

Dec 17 '06 #6
Yes, I tried his query and received the following error message: -

---------------------------------------------------------------------------------

Server: Msg 512, Level 16, State 1, Line 1
Subquery returned more than 1 value. This is not permitted when the
subquery follows =, !=, <, <= , >, >= or when the subquery is used as
an expression.
The statement has been terminated.

---------------------------------------------------------------------------------

David Portas wrote:
in**@bodykind.com wrote:
The following query appears to work correctly in SQL server, the only
problem (and it is a major problem) is that it sets the value of the
stock field to null on every record except the one that it is reducing.

Any ideas?

----------------------------------------------------------------------------------------------------

Did you try the query that Gert-Jan posted?

--
David Portas, SQL Server MVP

Whenever possible please post enough code to reproduce your problem.
Including CREATE TABLE and INSERT statements usually helps.
State what version of SQL Server you are using and specify the content
of any error messages.

SQL Server Books Online:
http://msdn2.microsoft.com/library/m...S,SQL.90).aspx
--
Dec 17 '06 #7
in**@bodykind.com wrote:
The following query appears to work correctly in SQL server, the only
problem (and it is a major problem) is that it sets the value of the
stock field to null on every record except the one that it is reducing.

Any ideas?

----------------------------------------------------------------------------------------------------
UPDATE Products

SET Products.Stock = Products.Stock -

(
select sum(OrdersProducts.Quantity)
from OrdersProducts
where ordersproducts.ProductID=products.ProductID and
ordersproducts.orderid = 63116 group by ordersproducts.ProductID
)

FROM Products
Change
sum(OrdersProducts.Quantity)
to
coalesce(sum(OrdersProducts.Quantity),0)

Alternatively, append the WHERE EXISTS portion of Gert-Jan's query.
Dec 17 '06 #8
>Subquery returned more than 1 value. This is not permitted when the subquery follows =, !=, <, <= , >, >= or when the subquery is used as an expression. <<

This tells you something very important about your data, namely that
your OrdersProducts or Products table or both have several occurences
of the same product_id in this order. Run the query by itself and find
the problem.

SELECT P.product_id
FROM OrdersProducts AS OP, Products AS P
WHERE OP.product_id = P.product_id
AND OP.order_id = 63116
GROUP BY P.product_id
HAVING COUNT(*) 1;

Since you did nopt post DDL, nobody can help any further. Oh, in case
some suggests using an UPDATE.. FROM.. syntax do not do it. That will
grab a random row from the subquery and use it -- totally scrambling
your database.

As a bit of education, you need to look up a good book on SQL to see
how the language really works. ACCESS is so far from SQL that it takes
a year to un-learn it; until then you are in danger writing SQL that
runs -- BUT not the way you meant it to.

I cleaned up your vague data element names and modified your original
ACCESS statement:

UPDATE (OrdersProducts AS OP
INNER JOIN
Products AS P
ON OP.product_id = P.product_id) AS Foobar
SET P.Stock = (P.stock_qty - OP.order_qty)
WHERE OP.order_id = 63116;

What a subquery expression in Standard SQL says is that we materialize
a working table, named Foobar in this example. If this syntax were
valid and consistent, then the UPDATE would apply to Foobar, not any of
the base tables!! Then the materialized table would disappear.
Nothing would have happened.

An UPDATE statement works on one and only one base table (or an
updatable VIEW that resolves to a single base table). If you could do
more than one table, then you would update the same rows multiple times
from the various JOINs.

Dec 17 '06 #9
in**@bodykind.com (in**@bodykind.com) writes:
The following query appears to work correctly in SQL server, the only
problem (and it is a major problem) is that it sets the value of the
stock field to null on every record except the one that it is reducing.
That's rude.
--------------------------------------------------------------------------
--------------------------
UPDATE Products

SET Products.Stock = Products.Stock -

(
select sum(OrdersProducts.Quantity)
from OrdersProducts
where ordersproducts.ProductID=products.ProductID and
ordersproducts.orderid = 63116 group by ordersproducts.ProductID
)

FROM Products
Since there is no WHERE clause to restrict the update, all rows are
updated.

It may work better if you attach Gert-Jan's WHERE clause:
> WHERE EXISTS (
SELECT *
FROM OrdersProducts
WHERE OrdersProducts.ProductID = Products.ProductID
AND OrdersProducts.OrderID=63116
)
It's interesting that Gert-Jan's query failed with "Subquery returned more
than 1 value." That would indicate that your Access query is not correct
either. Then again, I don't know Access or Jet, so maybe it does what
you want to after all.

Here is is yet one more suggestion:

UPDATE Products
SET Stock = P.Stock - OP.Quantity
FROM Products P
JOIN (SELECT ProductID, Quantity = SUM(Quantity)
FROM OrderProducts
WHERE OrderID = 63116
GROUP BY ProductID) AS OP ON P.ProductID = OP.ProductID

This syntax is my personal preference, in terms of simplicity and under-
standability. It is also likely to be the best performancewise. But it
has the disctinct advantage that it only works on SQL Server, so if you
want a solution that works both on Access and SQL Server, this is not
for you.


--
Erland Sommarskog, SQL Server MVP, es****@sommarskog.se

Books Online for SQL Server 2005 at
http://www.microsoft.com/technet/pro...ads/books.mspx
Books Online for SQL Server 2000 at
http://www.microsoft.com/sql/prodinf...ons/books.mspx
Dec 17 '06 #10
Erland, your SQL worked perfectly. Have tested it on several different
orders and works fine. I only want the solution to work in SQL Server
anyway so it's not a problem if it won't work in access.

For your information there are supposed to be multiple records in the
ordersproducts table with the same productid as we have products which
have different colours which are recorded in a seperate table. We don't
keep a record of the stock of each individual colour just the total
number in stock.

Once again, many thanks to everyone you has contributed, I would never
have found that solution on my own.
Erland Sommarskog wrote:
in**@bodykind.com (in**@bodykind.com) writes:
The following query appears to work correctly in SQL server, the only
problem (and it is a major problem) is that it sets the value of the
stock field to null on every record except the one that it is reducing.

That's rude.
--------------------------------------------------------------------------
--------------------------
UPDATE Products

SET Products.Stock = Products.Stock -

(
select sum(OrdersProducts.Quantity)
from OrdersProducts
where ordersproducts.ProductID=products.ProductID and
ordersproducts.orderid = 63116 group by ordersproducts.ProductID
)

FROM Products

Since there is no WHERE clause to restrict the update, all rows are
updated.

It may work better if you attach Gert-Jan's WHERE clause:
WHERE EXISTS (
SELECT *
FROM OrdersProducts
WHERE OrdersProducts.ProductID = Products.ProductID
AND OrdersProducts.OrderID=63116
)

It's interesting that Gert-Jan's query failed with "Subquery returned more
than 1 value." That would indicate that your Access query is not correct
either. Then again, I don't know Access or Jet, so maybe it does what
you want to after all.

Here is is yet one more suggestion:

UPDATE Products
SET Stock = P.Stock - OP.Quantity
FROM Products P
JOIN (SELECT ProductID, Quantity = SUM(Quantity)
FROM OrderProducts
WHERE OrderID = 63116
GROUP BY ProductID) AS OP ON P.ProductID = OP.ProductID

This syntax is my personal preference, in terms of simplicity and under-
standability. It is also likely to be the best performancewise. But it
has the disctinct advantage that it only works on SQL Server, so if you
want a solution that works both on Access and SQL Server, this is not
for you.


--
Erland Sommarskog, SQL Server MVP, es****@sommarskog.se

Books Online for SQL Server 2005 at
http://www.microsoft.com/technet/pro...ads/books.mspx
Books Online for SQL Server 2000 at
http://www.microsoft.com/sql/prodinf...ons/books.mspx
Dec 17 '06 #11
Erland, your SQL worked perfectly. Have tested it on several different
orders and works fine. I only want the solution to work in SQL Server
anyway so it's not a problem if it won't work in access.

For your information there are supposed to be multiple records in the
ordersproducts table with the same productid as we have products which
have different colours which are recorded in a seperate table. We don't
keep a record of the stock of each individual colour just the total
number in stock.

Once again, many thanks to everyone who has contributed, I would never
have found that solution on my own.
Erland Sommarskog wrote:
in**@bodykind.com (in**@bodykind.com) writes:
The following query appears to work correctly in SQL server, the only
problem (and it is a major problem) is that it sets the value of the
stock field to null on every record except the one that it is reducing.

That's rude.
--------------------------------------------------------------------------
--------------------------
UPDATE Products

SET Products.Stock = Products.Stock -

(
select sum(OrdersProducts.Quantity)
from OrdersProducts
where ordersproducts.ProductID=products.ProductID and
ordersproducts.orderid = 63116 group by ordersproducts.ProductID
)

FROM Products

Since there is no WHERE clause to restrict the update, all rows are
updated.

It may work better if you attach Gert-Jan's WHERE clause:
WHERE EXISTS (
SELECT *
FROM OrdersProducts
WHERE OrdersProducts.ProductID = Products.ProductID
AND OrdersProducts.OrderID=63116
)

It's interesting that Gert-Jan's query failed with "Subquery returned more
than 1 value." That would indicate that your Access query is not correct
either. Then again, I don't know Access or Jet, so maybe it does what
you want to after all.

Here is is yet one more suggestion:

UPDATE Products
SET Stock = P.Stock - OP.Quantity
FROM Products P
JOIN (SELECT ProductID, Quantity = SUM(Quantity)
FROM OrderProducts
WHERE OrderID = 63116
GROUP BY ProductID) AS OP ON P.ProductID = OP.ProductID

This syntax is my personal preference, in terms of simplicity and under-
standability. It is also likely to be the best performancewise. But it
has the disctinct advantage that it only works on SQL Server, so if you
want a solution that works both on Access and SQL Server, this is not
for you.


--
Erland Sommarskog, SQL Server MVP, es****@sommarskog.se

Books Online for SQL Server 2005 at
http://www.microsoft.com/technet/pro...ads/books.mspx
Books Online for SQL Server 2000 at
http://www.microsoft.com/sql/prodinf...ons/books.mspx
Dec 17 '06 #12
in**@bodykind.com (in**@bodykind.com) writes:
Erland, your SQL worked perfectly. Have tested it on several different
orders and works fine. I only want the solution to work in SQL Server
anyway so it's not a problem if it won't work in access.
Glad to hear that it worked out!

I like to add that the thing parentheses is something called a derived
table. Logically, it is a temporary table within the query, but it is
not materialised, and the optimizer may recast computation order as long
as it does not affect the result. It's a very powerful feature to build
complex queries in SQL.

Derived tables are part of ANSI SQL, so it is that part which is special
for SQL Server. The proprietary part lies in the FROM clause which is not
part of ANSI SQL for the UPDATE and DELETE statement. (And the JOIN clause
is part of FROM.)
--
Erland Sommarskog, SQL Server MVP, es****@sommarskog.se

Books Online for SQL Server 2005 at
http://www.microsoft.com/technet/pro...ads/books.mspx
Books Online for SQL Server 2000 at
http://www.microsoft.com/sql/prodinf...ons/books.mspx
Dec 17 '06 #13

This discussion thread is closed

Replies have been disabled for this discussion.

Similar topics

3 posts views Thread by Prem | last post: by
8 posts views Thread by kieran | last post: by
4 posts views Thread by algroth | last post: by
18 posts views Thread by Dave | last post: by
3 posts views Thread by Anila | last post: by
9 posts views Thread by shapper | last post: by
reply views Thread by leo001 | last post: by

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.