SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


TSQL help


TSQL help

Author
Message
vsamantha35
vsamantha35
SSCertifiable
SSCertifiable (8K reputation)SSCertifiable (8K reputation)SSCertifiable (8K reputation)SSCertifiable (8K reputation)SSCertifiable (8K reputation)SSCertifiable (8K reputation)SSCertifiable (8K reputation)SSCertifiable (8K reputation)

Group: General Forum Members
Points: 7966 Visits: 1222
create table t1
(key int,
cnt int
)
insert into t1
select 2,5
union all
select 100,20
union all
select 4,8
union all
select 15,5

create table t2
(c1 int,
c2 int
)

insert into t2
select 1001,2
union all
select 82,100
union all
select 83,100
union all
select 84,100
union all
select 101,4
union all
select 102,4
union all
select 2000,15
union all
select 2001,15

Expected output should be as below:
First off, please execuse me if there is any issue with my language.

I have two tables, "t1" and "t2".
Based on the "cnt" column from t1 table, "key" value from t1 table we should repeat the Key value from t1 in table t2 based on the count "cnt" column. Basically, the "key" value has to be repeated "cnt" number of times and should be inserted into t2.
Also, we need to take the "c1" column into account, while repeating the rows. if we need to check the rows in t2 and if the "key" is not getting repeated "cnt" number of times in table t2, then we need to generate the extra rows to match the count.
for newly generated rows, we need make use of c1 column values repeatedly starting from 1st value for that particular "key" value/

For now, i am not looking of insertion, but I am looking for a select statement which returns rows as follows. Can anybody help?

c1 c2
1001,2
1001,2
1001,2
1001,2
1001,2

82,100
83,100
84,100
82,100
83,100
84,100
82,100
83,100
84,100
82,100
83,100
84,100
82,100
83,100
84,100
82,100
83,100
84,100
82,100
83,100

101,4
102,4
101,4
102,4
101,4
102,4
101,4
102,4

2000,15
2001,15
2000,15
2001,15
2000,15


Thanks,

Sam
ChrisM@Work
ChrisM@Work
SSC Guru
SSC Guru (157K reputation)SSC Guru (157K reputation)SSC Guru (157K reputation)SSC Guru (157K reputation)SSC Guru (157K reputation)SSC Guru (157K reputation)SSC Guru (157K reputation)SSC Guru (157K reputation)

Group: General Forum Members
Points: 157062 Visits: 21380
-- Works for cnt <= 10
-- Expand the inline tally for cnt > 10
;WITH Process AS (
SELECT t2.*, t1.cnt,
rn = ROW_NUMBER() OVER(PARTITION BY c2 ORDER BY c1)
FROM (SELECT c1, c2, GroupSize = COUNT(*) OVER(PARTITION BY c2) FROM #t2) t2
LEFT JOIN #t1 t1
ON t1.[key] = t2.c2
CROSS APPLY (
SELECT TOP(CAST(ROUND(t1.cnt/(GroupSize*1.0), 0) AS INT)) n
FROM (VALUES (0),(0),(0),(0),(0),(0),(0),(0),(0),(0)) d (n)
) x
)
SELECT c1, c2
FROM Process
WHERE cnt >= rn
ORDER BY c1


“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
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum








































































































































































SQLServerCentral


Search