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


Wildcard DB name in VIEW of Procedure - Possible?


Wildcard DB name in VIEW of Procedure - Possible?

Author
Message
Dave-993364
Dave-993364
Valued Member
Valued Member (65 reputation)Valued Member (65 reputation)Valued Member (65 reputation)Valued Member (65 reputation)Valued Member (65 reputation)Valued Member (65 reputation)Valued Member (65 reputation)Valued Member (65 reputation)

Group: General Forum Members
Points: 65 Visits: 338
Hi there,

I've been trying to figure out whether it's possible to have a Wildcard DB name in a SELECT query.

eg. Database1, Database2, Database3, Database4, Database5, Database6 all have the same schema - but for different aspects of the business.

What I would like to figure out to do is to run something like this:

SELECT Col1, Col2, Col3, Col4, Col5 FROM AllDatabases (where AllDatabases is a concatenation of Database1-6)

At the moment, the best solution i've come up with is to loop round all the DB's and place the results into a temporary table, then select the results from the temporary table.

HOWEVER - the list of DB's *could* change. Not often, but it's possible. Ideally it needs to be as dynamic as possible.

Am I barking up the wrong tree here, or should I just stick with the looped concatenation of the DB's ?

Dave
Neeraj Dwivedi
Neeraj Dwivedi
SSCommitted
SSCommitted (2K reputation)SSCommitted (2K reputation)SSCommitted (2K reputation)SSCommitted (2K reputation)SSCommitted (2K reputation)SSCommitted (2K reputation)SSCommitted (2K reputation)SSCommitted (2K reputation)

Group: General Forum Members
Points: 1989 Visits: 1341
Try using sp_msforeachdb.
Sean Lange
Sean Lange
SSC Guru
SSC Guru (61K reputation)SSC Guru (61K reputation)SSC Guru (61K reputation)SSC Guru (61K reputation)SSC Guru (61K reputation)SSC Guru (61K reputation)SSC Guru (61K reputation)SSC Guru (61K reputation)

Group: General Forum Members
Points: 61579 Visits: 17954
Many times using a cursor for this sort of thing seems like the only way to pull this off. sp_msforeachdb is just a cursor too. Neither of these approaches is bad but if you have a lot of databases it can be really slow. As another option you can use FOR XML to build a dynamic string.

Something like this. Once you are sure the dynamic string is correct just uncomment the sp_executesql. :-)


declare @SQL nvarchar(max)

;with DatabaseList as
(
select name
from sys.databases
where database_id > 4
and name not in ('ReportServer', 'ReportServerTempDB')
)

select top 1 @SQL =
stuff((
select 'union all select Col1, col2, col3, Col4, col5 from ' + name + '.dbo.YourTable '
from DatabaseList
FOR XML PATH('')), 1, 10, '')
from DatabaseList

select @SQL

--exec sp_executesql @statement = @SQL



_______________________________________________________________

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 Modens 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)
Dave-993364
Dave-993364
Valued Member
Valued Member (65 reputation)Valued Member (65 reputation)Valued Member (65 reputation)Valued Member (65 reputation)Valued Member (65 reputation)Valued Member (65 reputation)Valued Member (65 reputation)Valued Member (65 reputation)

Group: General Forum Members
Points: 65 Visits: 338
Thank you both for your prompt replies.

I will try these options and let you know which worked for me.

Thank you again

Dave
Jeff Moden
Jeff Moden
SSC Guru
SSC Guru (211K reputation)SSC Guru (211K reputation)SSC Guru (211K reputation)SSC Guru (211K reputation)SSC Guru (211K reputation)SSC Guru (211K reputation)SSC Guru (211K reputation)SSC Guru (211K reputation)

Group: General Forum Members
Points: 211665 Visits: 41977
Considering the title of this thread, please keep in mind that none of them will work in a VIEW.

--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.
If you think its expensive to hire a professional to do the job, wait until you hire an amateur. -- Red Adair

Helpful Links:
How to post code problems
How to post performance problems
Forum FAQs
Dave-993364
Dave-993364
Valued Member
Valued Member (65 reputation)Valued Member (65 reputation)Valued Member (65 reputation)Valued Member (65 reputation)Valued Member (65 reputation)Valued Member (65 reputation)Valued Member (65 reputation)Valued Member (65 reputation)

Group: General Forum Members
Points: 65 Visits: 338
Jeff - Thanks I'll bear this in mind.

I've now hit a minor hiccup.
I'm using the FOR XML route as this seems to be 99% ideal for wehat I need. but when I specify a special character, like '>', in the query, it doesn't reproduce the character, it simply just has '>' instead.

Same goes for '>' too (ie. <)

Any way round this?

Dave
Lynn Pettis
Lynn Pettis
SSC Guru
SSC Guru (93K reputation)SSC Guru (93K reputation)SSC Guru (93K reputation)SSC Guru (93K reputation)SSC Guru (93K reputation)SSC Guru (93K reputation)SSC Guru (93K reputation)SSC Guru (93K reputation)

Group: General Forum Members
Points: 93391 Visits: 38955
I'm not using the special characters you listed, but look closely at the code below at how I am using FOR XML PATH to concatenate the values. Incorporate what you see there into your code and see if that helps.



declare @TestData table(id int);

with e1(n) as (select row_number() over (order by (select null)) from (values (1),(1),(1),(1),(1),(1),(1),(1),(1),(1))dt(n))
insert into @TestData
select n from e1;

select * from @TestData;

-- Concatenate the data:

select
stuff((select ',' + cast(id as varchar)
from @TestData
order by id
for xml path(''),TYPE).value('.','varchar(max)'),1,1,'');




Cool
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)
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