Please start any new threads on our new
site at https://forums.sqlteam.com. We've got lots of great SQL Server
experts to answer whatever question you can come up with.
| Author |
Topic |
|
iqmcl
Starting Member
8 Posts |
Posted - 2010-03-03 : 11:48:45
|
| Hi,I have a table which looks like this;OrderID,ProductId,Qty=====================00001,1,400001,2,100001,3,2So the same order has 4 x product 1, 1 x product 2 and 2 x product 3.What I need to do is insert records into another table (based on the Qty field), so;OrderId,ProductId=================000001,1000001,1000001,1000001,1000001,2000001,3000001,3Can anyone help me out with this, I am not entirely sure of the best/cleanest approach!ThanksChris |
|
|
visakh16
Very Important crosS Applying yaK Herder
52326 Posts |
Posted - 2010-03-03 : 11:52:19
|
| [code]INSERT INTO Table2 (OrderID,ProductId)SELECT t1.OrderID,t1.ProductIdFROM Table1 t1CROSS JOIN master..spt_values vWHERE v.type='p'AND v.number BETWEEN 1 AND t1.Qty[/code]------------------------------------------------------------------------------------------------------SQL Server MVPhttp://visakhm.blogspot.com/ |
 |
|
|
ms65g
Constraint Violating Yak Guru
497 Posts |
Posted - 2010-03-03 : 19:08:32
|
| [code]INSERT INTO Table2 (OrderID,ProductId)SELECT t.OrderID,t.ProductId FROM Table1 T JOIN (SELECT ROW_NUMBER() OVER(ORDER BY (SELECT 1)) FROM (SELECT 1 UNION ALL SELECT 2 UNION ALL SELECT 3) D0(i) CROSS JOIN (SELECT 1 UNION ALL SELECT 2 UNION ALL SELECT 3) D1(i) CROSS JOIN (SELECT 1 UNION ALL SELECT 2 UNION ALL SELECT 3) D2(i) CROSS JOIN (SELECT 1 UNION ALL SELECT 2 UNION ALL SELECT 3) D3(i) CROSS JOIN (SELECT 1 UNION ALL SELECT 2 UNION ALL SELECT 3) D4(i) CROSS JOIN (SELECT 1 UNION ALL SELECT 2 UNION ALL SELECT 3) D5(i) CROSS JOIN (SELECT 1 UNION ALL SELECT 2 UNION ALL SELECT 3) D6(i) CROSS JOIN (SELECT 1 UNION ALL SELECT 2 UNION ALL SELECT 3) D7(i) CROSS JOIN (SELECT 1 UNION ALL SELECT 2 UNION ALL SELECT 3) D8(i) CROSS JOIN (SELECT 1 UNION ALL SELECT 2 UNION ALL SELECT 3) D9(i) CROSS JOIN (SELECT 1 UNION ALL SELECT 2 UNION ALL SELECT 3) D10(i)) D(n) ON D.n <= T.Qty[/code] |
 |
|
|
madhivanan
Premature Yak Congratulator
22864 Posts |
Posted - 2010-03-04 : 02:31:00
|
quote: Originally posted by ms65g
INSERT INTO Table2 (OrderID,ProductId)SELECT t.OrderID,t.ProductId FROM Table1 T JOIN (SELECT ROW_NUMBER() OVER(ORDER BY (SELECT 1)) FROM (SELECT 1 UNION ALL SELECT 2 UNION ALL SELECT 3) D0(i) CROSS JOIN (SELECT 1 UNION ALL SELECT 2 UNION ALL SELECT 3) D1(i) CROSS JOIN (SELECT 1 UNION ALL SELECT 2 UNION ALL SELECT 3) D2(i) CROSS JOIN (SELECT 1 UNION ALL SELECT 2 UNION ALL SELECT 3) D3(i) CROSS JOIN (SELECT 1 UNION ALL SELECT 2 UNION ALL SELECT 3) D4(i) CROSS JOIN (SELECT 1 UNION ALL SELECT 2 UNION ALL SELECT 3) D5(i) CROSS JOIN (SELECT 1 UNION ALL SELECT 2 UNION ALL SELECT 3) D6(i) CROSS JOIN (SELECT 1 UNION ALL SELECT 2 UNION ALL SELECT 3) D7(i) CROSS JOIN (SELECT 1 UNION ALL SELECT 2 UNION ALL SELECT 3) D8(i) CROSS JOIN (SELECT 1 UNION ALL SELECT 2 UNION ALL SELECT 3) D9(i) CROSS JOIN (SELECT 1 UNION ALL SELECT 2 UNION ALL SELECT 3) D10(i)) D(n) ON D.n <= T.Qty
It is better to have a number table and cross join with it. If you generate numbers on the fly it may cause performance issues for large set of dataMadhivananFailing to plan is Planning to fail |
 |
|
|
|
|
|
|
|