Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase

Update FIELD from Select Aggregated Statement on second table Expand / Collapse
Author
Message
Posted Thursday, April 10, 2014 5:02 AM
SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: Tuesday, September 23, 2014 3:18 AM
Points: 177, Visits: 418
Hi all,
I have a Warehouse Layout table which contains the warehouse and locations, which I would like to populate with stock quantities from another table ( aggregated )

The code I have is as below -


update
[dbo].[SLGWarehouseLayout]
set Qty =
(
Select
InvMultBin.Warehouse, InvMultBin.Bin,
SubString( InvMultBin.Bin, 1, 1 ) as xx,
SubString( InvMultBin.Bin, 3, 2 ) as yy,
SubString( InvMultBin.Bin, 2, 1 ) as zz,
Sum( QtyOnHand1 ) as TotalStock
from InvMultBin
join [SLGWarehouseLayout]
on
SubString( InvMultBin.Bin, 1, 1 ) = SubString( [dbo].[SLGWarehouseLayout].Rack,1,1 ) and
SubString( InvMultBin.Bin, 3, 2 ) = SubString( [dbo].[SLGWarehouseLayout].Bay ,1,2) and
SubString( InvMultBin.Bin, 2, 1 ) = SubString( [dbo].[SLGWarehouseLayout].Height,1,1 )

where InvMultBin.Warehouse in ( 'W1','SC') and QtyOnHand1 <> 0
group by InvMultBin.Warehouse, InvMultBin.Bin having Sum( QtyOnHand1 ) > 0
)


But I get the following error message ;
Msg 116, Level 16, State 1, Line 2
Only one expression can be specified in the select list when the subquery is not introduced with EXISTS.


any help would be appreciated -



________________________________________________________________________________________________
Regards
Steve
SQL 2008 DBA/DBD - MCTS/MCITP

Please don't trust me, test the solutions I give you before using them.
Post #1560357
Posted Thursday, April 10, 2014 5:10 AM
SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: Friday, October 10, 2014 8:50 AM
Points: 124, Visits: 148
Hi Steve,

it looks to me as though you are trying to update the QTY column using a sub query that brings back more than one column. Change the select to assign only one value to the QTY and you should be fine.

is this actually a syntax error and you were trying to use a derived table?

thanks

J
Post #1560359
Posted Thursday, April 10, 2014 5:24 AM
SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: Tuesday, September 23, 2014 3:18 AM
Points: 177, Visits: 418
Ahh right - sorry - yes I was playing with just the SELECT part of the query - which returns correctly and then I forgot to uncomment the bin, Rack

But when I run it - I appear to get the incorrect totals populate into the holding table, rather than the ones returned from the inner SELECT statement.

Regards


________________________________________________________________________________________________
Regards
Steve
SQL 2008 DBA/DBD - MCTS/MCITP

Please don't trust me, test the solutions I give you before using them.
Post #1560367
Posted Thursday, April 10, 2014 7:05 AM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Yesterday @ 9:54 AM
Points: 6,813, Visits: 14,028
The inner select is uncorrelated - it will update every row of the target.

Which table contains column QtyOnHand1?


“Write the query the simplest way. If through testing it becomes clear that the performance is inadequate, consider alternative query forms.” - Gail Shaw

For fast, accurate and documented assistance in answering your questions, please read this article.
Understanding and using APPLY, (I) and (II) Paul White
Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden
Exploring Recursive CTEs by Example Dwain Camps
Post #1560408
Posted Thursday, April 10, 2014 7:43 AM This worked for the OP Answer marked as solution


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Yesterday @ 9:54 AM
Points: 6,813, Visits: 14,028
Here's a guess:


-- ALWAYS check first using a SELECT
SELECT
l.rack, l.bay, l.height, l.qty, x.TotalStock, x.Warehouse, x.Bin
FROM [SLGWarehouseLayout] l
CROSS APPLY (
SELECT SUM(i.QtyOnHand1) AS TotalStock, i.Warehouse, i.Bin
FROM InvMultBin i
WHERE i.Warehouse IN ('W1','SC')
AND i.QtyOnHand1 <> 0
AND LEFT(i.Bin, 1) = LEFT(l.Rack, 1)
AND SUBSTRING(i.Bin, 3, 2) = LEFT(l.Bay, 2)
AND SUBSTRING(i.Bin, 2, 1) = LEFT(l.Height, 1)
GROUP BY i.Warehouse, i.Bin
HAVING SUM(i.QtyOnHand1) > 0
) x

-- If the SELECT works, convert it to the UPDATE equivalent
UPDATE l SET
qty = x.TotalStock
FROM [SLGWarehouseLayout] l
CROSS APPLY (
SELECT SUM(i.QtyOnHand1) AS TotalStock
FROM InvMultBin i
WHERE i.Warehouse IN ('W1','SC')
AND i.QtyOnHand1 <> 0
AND LEFT(i.Bin, 1) = LEFT(l.Rack, 1)
AND SUBSTRING(i.Bin, 3, 2) = LEFT(l.Bay, 2)
AND SUBSTRING(i.Bin, 2, 1) = LEFT(l.Height, 1)
GROUP BY i.Warehouse, i.Bin
HAVING SUM(i.QtyOnHand1) > 0
) x



“Write the query the simplest way. If through testing it becomes clear that the performance is inadequate, consider alternative query forms.” - Gail Shaw

For fast, accurate and documented assistance in answering your questions, please read this article.
Understanding and using APPLY, (I) and (II) Paul White
Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden
Exploring Recursive CTEs by Example Dwain Camps
Post #1560436
Posted Thursday, April 10, 2014 7:53 AM
SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: Tuesday, September 23, 2014 3:18 AM
Points: 177, Visits: 418
Totally brilliant - thank you.

In the meantime I have used the PIVOT function to create a View - dropped into Excel and then conditional formatting to show the current warehouse stock population.

Thank you for the help

Regards
Steve


________________________________________________________________________________________________
Regards
Steve
SQL 2008 DBA/DBD - MCTS/MCITP

Please don't trust me, test the solutions I give you before using them.
Post #1560438
Posted Thursday, April 10, 2014 9:29 AM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Yesterday @ 9:54 AM
Points: 6,813, Visits: 14,028
You're welcome. Thanks for the feedback. If you have any questions about the solution, post back.

“Write the query the simplest way. If through testing it becomes clear that the performance is inadequate, consider alternative query forms.” - Gail Shaw

For fast, accurate and documented assistance in answering your questions, please read this article.
Understanding and using APPLY, (I) and (II) Paul White
Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden
Exploring Recursive CTEs by Example Dwain Camps
Post #1560503
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse