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

Wildcard DB name in VIEW of Procedure - Possible? Expand / Collapse
Author
Message
Posted Tuesday, April 16, 2013 9:31 AM
Grasshopper

GrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopper

Group: General Forum Members
Last Login: Today @ 8:09 AM
Points: 11, Visits: 244
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
Post #1442810
Posted Tuesday, April 16, 2013 9:36 AM
SSC Eights!

SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!

Group: General Forum Members
Last Login: Tuesday, August 26, 2014 5:30 AM
Points: 811, Visits: 1,165
Try using sp_msforeachdb.
Post #1442814
Posted Tuesday, April 16, 2013 10:08 AM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Friday, August 29, 2014 2:32 PM
Points: 13,302, Visits: 12,168
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 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 #1442836
Posted Tuesday, April 16, 2013 10:22 AM
Grasshopper

GrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopper

Group: General Forum Members
Last Login: Today @ 8:09 AM
Points: 11, Visits: 244
Thank you both for your prompt replies.

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

Thank you again

Dave
Post #1442844
Posted Tuesday, April 16, 2013 4:28 PM


SSC-Dedicated

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

Group: General Forum Members
Last Login: Yesterday @ 9:58 AM
Points: 36,995, Visits: 31,517
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."

(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 #1443048
Posted Wednesday, April 17, 2013 3:18 AM
Grasshopper

GrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopper

Group: General Forum Members
Last Login: Today @ 8:09 AM
Points: 11, Visits: 244
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
Post #1443154
Posted Wednesday, April 17, 2013 6:18 AM


SSC-Insane

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

Group: General Forum Members
Last Login: Today @ 5:35 PM
Points: 23,300, Visits: 32,052
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,'');





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 #1443215
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse