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


Is a Dynamic SQL solution possible in this case ?


Is a Dynamic SQL solution possible in this case ?

Author
Message
sqlislife
sqlislife
Old Hand
Old Hand (333 reputation)Old Hand (333 reputation)Old Hand (333 reputation)Old Hand (333 reputation)Old Hand (333 reputation)Old Hand (333 reputation)Old Hand (333 reputation)Old Hand (333 reputation)

Group: General Forum Members
Points: 333 Visits: 194
Hey Guys,
I have a table with the following data.

Create Table #Temp
(ID INT, MYID INT, TITLE VARCHAR(20))
INSERT INTO #Temp
Select 1, 1, 'First' UNION ALL
Select 1, 2, 'Second' UNION ALL
Select 1, 3, 'Third' UNION ALL
Select 1, 4, 'Fourth' UNION ALL
Select 1, 5, 'Fifth' UNION ALL
Select 1, 6, 'Sixth' UNION ALL
Select 1, 7, 'Seventh' UNION ALL
Select 1, 8, 'Eighth' UNION ALL
Select 1, 9, 'Ninth' UNION ALL
Select 1, 10, 'Tenth' UNION ALL
Select 2, 3, 'Third' UNION ALL
Select 2, 4, 'Fourth' UNION ALL
Select 2, 5, 'Fifth' UNION ALL
Select 2, 6, 'Sixth' UNION ALL
Select 2, 7, 'Seventh' UNION ALL
Select 2, 8, 'Eighth' UNION ALL
Select 2, 9, 'Ninth' UNION ALL
Select 3, 1, 'First' UNION ALL
Select 3, 2, 'Second' UNION ALL
Select 3, 3, 'Third' UNION ALL
Select 3, 4, 'Fourth' UNION ALL
Select 3, 5, 'Fifth' UNION ALL
Select 3, 6, 'Sixth' UNION ALL
Select 3, 7, 'Seventh' UNION ALL
Select 3, 8, 'Eighth'
Select * from #Temp


I am trying to get an intersect of each ID value. The result should look something like this ;

Create Table #TempIntersect
(MYID INT, TITLE VARCHAR(20))
INSERT INTO #TempIntersect
Select MYID, TITLE from #temp
where id = 1
intersect
Select MYID, TITLE from #temp
where id = 2
intersect
Select MYID, TITLE from #temp
where id = 3
Select * from #TempIntersect


Here are my questions,

1. Is there any other method more optimal than the intersect function ? It seems to be the simplest way to achieve this but I know it's rarely used.

2. This is the main question, in the future, there will be more IDs added to this table, how can this be dynamically re-written so that I don't have to modify it
everytime an ID has been added ? The ideal solution will dynamically create all the intersect statements based on the number of IDs.

For example, if we added the following into the #Temp table

INSERT INTO #TEMP
Select 4, 4, 'Fourth' UNION ALL
Select 4, 5, 'Fifth' UNION ALL
Select 4, 6, 'Sixth' UNION ALL
Select 4, 7, 'Seventh' UNION ALL
Select 4, 8, 'Eighth' UNION ALL
Select 4, 9, 'Ninth'

The query should somehow be able to dynamically create a fourth select statement without me going to modify it. Something like this;

Select MYID, TITLE from #temp
where id = 1
intersect
Select MYID, TITLE from #temp
where id = 2
intersect
Select MYID, TITLE from #temp
where id = 3
intersect
Select MYID, TITLE from #temp
where id = 4

Thanks guys.
Luis Cazares
Luis Cazares
SSC Guru
SSC Guru (64K reputation)SSC Guru (64K reputation)SSC Guru (64K reputation)SSC Guru (64K reputation)SSC Guru (64K reputation)SSC Guru (64K reputation)SSC Guru (64K reputation)SSC Guru (64K reputation)

Group: General Forum Members
Points: 64861 Visits: 20225
There's no need to use dynamic code. Here's one option and maybe someone could give a better one because I'm not so sure on its performance with big loads. It's quite simple though. :-)

SELECT MYID,
TITLE
FROM #Temp
GROUP BY MYID,
TITLE
HAVING COUNT(*) = (SELECT COUNT( DISTINCT ID) FROM #Temp)
ORDER BY MYID,
TITLE




Luis C.
General Disclaimer:
Are you seriously taking the advice and code from someone from the internet without testing it? Do you at least understand it? Or can it easily kill your server?


How to post data/code on a forum to get the best help: Option 1 / Option 2
dwain.c
dwain.c
One Orange Chip
One Orange Chip (28K reputation)One Orange Chip (28K reputation)One Orange Chip (28K reputation)One Orange Chip (28K reputation)One Orange Chip (28K reputation)One Orange Chip (28K reputation)One Orange Chip (28K reputation)One Orange Chip (28K reputation)

Group: General Forum Members
Points: 28389 Visits: 6431
Luis Cazares (12/11/2013)
There's no need to use dynamic code. Here's one option and maybe someone could give a better one because I'm not so sure on its performance with big loads. It's quite simple though. :-)

SELECT MYID,
TITLE
FROM #Temp
GROUP BY MYID,
TITLE
HAVING COUNT(*) = (SELECT COUNT( DISTINCT ID) FROM #Temp)
ORDER BY MYID,
TITLE



+1

Unless of course you allow duplicates in your table, like the last row in the following:


INSERT INTO #Temp
Select 1, 1, 'First' UNION ALL
Select 1, 2, 'Second' UNION ALL
Select 1, 3, 'Third' UNION ALL
Select 1, 4, 'Fourth' UNION ALL
Select 1, 5, 'Fifth' UNION ALL
Select 1, 6, 'Sixth' UNION ALL
Select 1, 7, 'Seventh' UNION ALL
Select 1, 8, 'Eighth' UNION ALL
Select 1, 9, 'Ninth' UNION ALL
Select 1, 10, 'Tenth' UNION ALL
Select 2, 3, 'Third' UNION ALL
Select 2, 4, 'Fourth' UNION ALL
Select 2, 5, 'Fifth' UNION ALL
Select 2, 6, 'Sixth' UNION ALL
Select 2, 7, 'Seventh' UNION ALL
Select 2, 8, 'Eighth' UNION ALL
Select 2, 9, 'Ninth' UNION ALL
Select 3, 1, 'First' UNION ALL
Select 3, 2, 'Second' UNION ALL
Select 3, 3, 'Third' UNION ALL
Select 3, 4, 'Fourth' UNION ALL
Select 3, 5, 'Fifth' UNION ALL
Select 3, 6, 'Sixth' UNION ALL
Select 3, 7, 'Seventh' UNION ALL
Select 3, 8, 'Eighth' UNION ALL
Select 3, 8, 'Eighth';




I believe what Luis has done could be modified for this case, but I'll leave that to you if you say it can happen.


My mantra: No loops! No CURSORs! No RBAR! Hoo-uh!

My thought question: Have you ever been told that your query runs too fast?

My advice:
INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.


Need to UNPIVOT? Why not CROSS APPLY VALUES instead?
Since random numbers are too important to be left to chance, let's generate some!
Learn to understand recursive CTEs by example.
Splitting strings based on patterns can be fast!
My temporal SQL musings: Calendar Tables, an Easter SQL, Time Slots and Self-maintaining, Contiguous Effective Dates in Temporal Tables
sqlislife
sqlislife
Old Hand
Old Hand (333 reputation)Old Hand (333 reputation)Old Hand (333 reputation)Old Hand (333 reputation)Old Hand (333 reputation)Old Hand (333 reputation)Old Hand (333 reputation)Old Hand (333 reputation)

Group: General Forum Members
Points: 333 Visits: 194
Sorry about the late response but this works for what I am trying to do. I will try and expand on it. Thanks guys
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