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 12»»

Add variable number of rows into a table based on the values in another table (without cursors/while loops) Expand / Collapse
Author
Message
Posted Wednesday, March 20, 2013 12:46 PM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Monday, June 17, 2013 10:26 PM
Points: 9, Visits: 151
Below is a simplified version of my tables:

set nocount on
drop table #x
create table #x (docid int, pages int)
insert into #x values (1, 1)
insert into #x values (2, 5)
insert into #x values (3, 2)
insert into #x values (4, 3)

select * from #x;

drop table #y
create table #y (docid int, pagenumber int)
insert into #y values (1, 1)
insert into #y values (2, 1)
insert into #y values (2, 2)
insert into #y values (2, 3)
insert into #y values (2, 4)
insert into #y values (2, 5)
insert into #y values (3, 1)
insert into #y values (3, 2)
insert into #y values (4, 1)
insert into #y values (4, 2)
insert into #y values (4, 3)

select * from #y;

set nocount off

So basically I have an input table #x with a docid and total number of pages within that docid.
How can I construct the output table #y that has n rows per #x.docid where n is #x.pages?
I can do it with cursors or while loops etc in a few different ways (either per docid or one insert/select per distinct #x.pages value)

I am wondering if there is a set based T-SQL solution to this? Can CTEs be somehow used for this?
I am creating code ultimately for SQL Server 2008 R2 enterprise edition.

Any help is greatly appreciated!

Thanks.
Post #1433421
Posted Wednesday, March 20, 2013 1:06 PM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Today @ 9:29 AM
Points: 11,994, Visits: 11,012
Sure this isn't too hard using a tally table.

insert #y
select #x.DocID, t.N
from #x
join tally t on t.N <= #x.pages

select * from #y

You can read about a tally table here. http://www.sqlservercentral.com/articles/T-SQL/62867/


_______________________________________________________________

Need help? Help us help you.

Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

Need to split a string? Try Jeff Moden's splitter.

Cross Tabs and Pivots, Part 1 – Converting Rows to Columns
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs
Understanding and Using APPLY (Part 1)
Understanding and Using APPLY (Part 2)
Post #1433435
Posted Wednesday, March 20, 2013 1:16 PM


SSC-Insane

SSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-Insane

Group: General Forum Members
Last Login: Today @ 8:10 AM
Points: 22,514, Visits: 30,241
Sean Lange (3/20/2013)
Sure this isn't too hard using a tally table.

insert #y
select #x.DocID, t.N
from #x
join tally t on t.N <= #x.pages

select * from #y

You can read about a tally table here. http://www.sqlservercentral.com/articles/T-SQL/62867/


I'm starting to see a pattern with some of the posts. Looks like people are coming here to get their homework done. Anyone else seeing this?



Lynn Pettis

For better assistance in answering your questions, click here
For tips to get better help with Performance Problems, click here
For Running Totals and its variations, click here or when working with partitioned tables
For more about Tally Tables, click here
For more about Cross Tabs and Pivots, click here and here
Managing Transaction Logs

SQL Musings from the Desert Fountain Valley SQL (My Mirror Blog)
Post #1433440
Posted Wednesday, March 20, 2013 1:24 PM


SSC-Dedicated

SSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-Dedicated

Group: General Forum Members
Last Login: Today @ 8:53 AM
Points: 35,983, Visits: 30,273
Lynn Pettis (3/20/2013)
Sean Lange (3/20/2013)
Sure this isn't too hard using a tally table.

insert #y
select #x.DocID, t.N
from #x
join tally t on t.N <= #x.pages

select * from #y

You can read about a tally table here. http://www.sqlservercentral.com/articles/T-SQL/62867/


I'm starting to see a pattern with some of the posts. Looks like people are coming here to get their homework done. Anyone else seeing this?


Yep... I'm thinking the instructor is going to make a mess in his britches when everyone turns in the Tally Table solution. Hopefully, the instructor learns something in the process.


--Jeff Moden
"RBAR is pronounced "ree-bar" and is a "Modenism" for "Row-By-Agonizing-Row".

First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column."

"Change is inevitable. Change for the better is not." -- 04 August 2013
(play on words) "Just because you CAN do something in T-SQL, doesn't mean you SHOULDN'T." --22 Aug 2013

Helpful Links:
How to post code problems
How to post performance problems
Post #1433448
Posted Wednesday, March 20, 2013 1:29 PM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Today @ 9:29 AM
Points: 11,994, Visits: 11,012
Jeff Moden (3/20/2013)
Lynn Pettis (3/20/2013)
Sean Lange (3/20/2013)
Sure this isn't too hard using a tally table.

insert #y
select #x.DocID, t.N
from #x
join tally t on t.N <= #x.pages

select * from #y

You can read about a tally table here. http://www.sqlservercentral.com/articles/T-SQL/62867/


I'm starting to see a pattern with some of the posts. Looks like people are coming here to get their homework done. Anyone else seeing this?


Yep... I'm thinking the instructor is going to make a mess in his britches when everyone turns in the Tally Table solution. Hopefully, the instructor learns something in the process.


LOL. I guess my "homework meter" has been temporarily disabled. It should be back online in the next few minutes.


_______________________________________________________________

Need help? Help us help you.

Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

Need to split a string? Try Jeff Moden's splitter.

Cross Tabs and Pivots, Part 1 – Converting Rows to Columns
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs
Understanding and Using APPLY (Part 1)
Understanding and Using APPLY (Part 2)
Post #1433452
Posted Wednesday, March 20, 2013 1:30 PM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Monday, June 17, 2013 10:26 PM
Points: 9, Visits: 151
Thank you Sir! Not sure how to interpret the other replies and so I will leave it at that. The article was really helpful. Thank you again.
Post #1433454
Posted Wednesday, March 20, 2013 1:34 PM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Today @ 9:29 AM
Points: 11,994, Visits: 11,012
charles99 (3/20/2013)
Thank you Sir! Not sure how to interpret the other replies and so I will leave it at that. The article was really helpful. Thank you again.


You are welcome.

The other replies are in response to some people that come here and post their homework questions. There is nothing wrong with that per se but if you are a student then it is a disservice by myself or any other posters to simply provide the answer. Sort of the old "teach a man to fish" concept.


_______________________________________________________________

Need help? Help us help you.

Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

Need to split a string? Try Jeff Moden's splitter.

Cross Tabs and Pivots, Part 1 – Converting Rows to Columns
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs
Understanding and Using APPLY (Part 1)
Understanding and Using APPLY (Part 2)
Post #1433455
Posted Wednesday, March 20, 2013 1:55 PM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Monday, June 17, 2013 10:26 PM
Points: 9, Visits: 151
I see ... I wish I were still a student. The pros are making me nervous asking my next "real-world" question on this site again! :)
Post #1433462
Posted Wednesday, March 20, 2013 2:09 PM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Today @ 9:29 AM
Points: 11,994, Visits: 11,012
charles99 (3/20/2013)
I see ... I wish I were still a student. The pros are making me nervous asking my next "real-world" question on this site again! :)


Don't worry about it. There was something in the way you had worded your post that made it sound as though it might be a homework type question. Ask away, somebody will come along and help.


_______________________________________________________________

Need help? Help us help you.

Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

Need to split a string? Try Jeff Moden's splitter.

Cross Tabs and Pivots, Part 1 – Converting Rows to Columns
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs
Understanding and Using APPLY (Part 1)
Understanding and Using APPLY (Part 2)
Post #1433472
Posted Wednesday, March 20, 2013 3:50 PM


SSC-Insane

SSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-Insane

Group: General Forum Members
Last Login: Today @ 8:10 AM
Points: 22,514, Visits: 30,241
charles99 (3/20/2013)
I see ... I wish I were still a student. The pros are making me nervous asking my next "real-world" question on this site again! :)


The question you asked has properties very similar to several questions asked by others, so it really is just the pattern that set off a "possible homework" alarm. We are more than willing to help. If we know it is homework, we tend to take a more hands off approach (or at least try to) and try to guide instead just answering the question.

We want people to understand what they are doing. For real world questions, we'll answer than normal work backward on the understanding side because you are still the one who will get the call at 3:30 in the morning when things break, not us.



Lynn Pettis

For better assistance in answering your questions, click here
For tips to get better help with Performance Problems, click here
For Running Totals and its variations, click here or when working with partitioned tables
For more about Tally Tables, click here
For more about Cross Tabs and Pivots, click here and here
Managing Transaction Logs

SQL Musings from the Desert Fountain Valley SQL (My Mirror Blog)
Post #1433519
« Prev Topic | Next Topic »

Add to briefcase 12»»

Permissions Expand / Collapse