Tek-Tips is the largest IT community on the Internet today!

Members share and learn making Tek-Tips Forums the best source of peer-reviewed technical information on the Internet!

  • Congratulations SkipVought on being selected by the Tek-Tips community for having the most helpful posts in the forums last week. Way to Go!

How to generate a number of rows based on a count in a table? 2

Status
Not open for further replies.

MdotButler

Programmer
Jan 18, 2006
104
0
0
US
I have a customer and inventory table. I have a need to create a result set that includes 1 row for each item in inventory. If there are 3 items in inventory for a item, it should generate 3 rows.

Code:
CustomersTable Structure
  custid
  name

CustomersTable Rows
  cust01 cust01name
  cust02 cust02name

ItemsTable Structure
  custid
  itemid
  count

ItemsTable Rows
  cust01 item01 2
  cust01 item02 3
  cust02 item01 3
  cust02 item03 2

Desired Result
  cust01 cust01name item01
  cust01 cust01name item01
  cust01 cust01name item02
  cust01 cust01name item02
  cust01 cust01name item02
  cust02 cust02name item01
  cust02 cust02name item01
  cust02 cust02name item01
  cust02 cust02name item03
  cust02 cust02name item03
I am sure there is a way but I am drawing a blank.

TIA
Mark
 
One way would be the use of a numbers table, joined on the ItemTable Count

Using a table "Numbers" with a single integer field entitled "Counter", fill it with the numbers 1 to 10 and try this:

Code:
SELECT CustomersTable.custid, CustomersTable.custname, ItemsTable.itemid from ItemsTable inner join CustomersTable on ItemsTable.custid = CustomersTable.custid inner join Numbers on Numbers.Counter <= ItemsTable.[count]

There are plenty of bits of code on the internet to quickly fill a numbers table with 1M lines, and many articles that show the use of a numbers table in T-SQL data wrangling; I commend such a table to you!

soi là, soi carré
 
Try:

Code:
with CTE as
(
    select c.custid, c.name, i.itemid, i.count, 1 as seq 
    from CustomersTable as c
    join ItemsTable as i on i.custid = c.custid 

    union all
    
    select r.custid, r.name, r.itemid, r.count, (r.seq + 1) as seq
    from CTE as r
    where r.seq < r.count
)

select r.custid, r.name, r.itemid 
from CTE as r
order by r.custid, r.itemid

Hope this helps.


Imoveis em Guarulhos
 
Thanx drlex. Solution worked like a champ.

Thanx imex. I did not use your solution as the first fit my requirements better based on the real problem, not the simple one I used in the question. I had not thought of using the union. I will have to file that one away for the next time.

Again thanx.
 
Status
Not open for further replies.

Part and Inventory Search

Sponsor

Back
Top