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


Query - Please Help!


Query - Please Help!

Author
Message
seraph67
seraph67
Forum Newbie
Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)

Group: General Forum Members
Points: 3 Visits: 69
Someone please tell me what I'm doing wrong..... Sad

All I want to do, is get a list of databases which don't have extended properties.

Query below:

exec ('create table #t_nodb(dbname varchar(120))
insert into #t_nodb (dbname)
exec sp_MSforeachdb ''if ''?'' in (''tempDB'') return
use ?
select ''?'' where ''?'' not in (select ''?'' from sys.extended_properties)''
select * from #t_nodb
drop table #t_nodb')

Thanks!
Erin Ramsay
Erin Ramsay
SSC Eights!
SSC Eights! (825 reputation)SSC Eights! (825 reputation)SSC Eights! (825 reputation)SSC Eights! (825 reputation)SSC Eights! (825 reputation)SSC Eights! (825 reputation)SSC Eights! (825 reputation)SSC Eights! (825 reputation)

Group: General Forum Members
Points: 825 Visits: 1099
This should get you started.

DECLARE @strSQL VARCHAR(max) 
DECLARE @dbaseName VARCHAR(255)
DECLARE proplist CURSOR local static forward_only read_only FOR
SELECT name
FROM sys.databases
WHERE database_id NOT IN ( 1, 2, 3, 4 )

OPEN proplist

FETCH next FROM proplist INTO @dbaseName

WHILE @@fetch_status = 0
BEGIN
SET @strSQL = 'use [' + @dbaseName
+
']; if not exists (select * from sys.extended_properties) select '''
+ @dbaseName + ''''

EXEC (@strSQL)

FETCH next FROM proplist INTO @dbaseName
END

CLOSE proplist

DEALLOCATE proplist


Sean Lange
Sean Lange
One Orange Chip
One Orange Chip (26K reputation)One Orange Chip (26K reputation)One Orange Chip (26K reputation)One Orange Chip (26K reputation)One Orange Chip (26K reputation)One Orange Chip (26K reputation)One Orange Chip (26K reputation)One Orange Chip (26K reputation)

Group: General Forum Members
Points: 26366 Visits: 17557
Since sp_msforeachdb and the good code posted by Erin both are cursors I figured I would take a shot at doing this without a cursor. This code should also work. It doesn't use a cursor and the results are all in a single table.


declare @MyQuery nvarchar(max) =
(
select 'select count(*) as PropertyCount, ''' + name + ''' as DBName from ' + name + '.sys.extended_properties union all '
from sys.databases
where database_id not in (1, 2, 3, 4)
for xml path('')
)

set @MyQuery = 'select DBName from (' + left(@MyQuery, len(@MyQuery) - 10) + ' )x where x.PropertyCount = 0 order by DBName'

exec sp_executesql @MyQuery




_______________________________________________________________

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)
Erin Ramsay
Erin Ramsay
SSC Eights!
SSC Eights! (825 reputation)SSC Eights! (825 reputation)SSC Eights! (825 reputation)SSC Eights! (825 reputation)SSC Eights! (825 reputation)SSC Eights! (825 reputation)SSC Eights! (825 reputation)SSC Eights! (825 reputation)

Group: General Forum Members
Points: 825 Visits: 1099
Nicely done, Sean.
ScottPletcher
ScottPletcher
SSCrazy Eights
SSCrazy Eights (8K reputation)SSCrazy Eights (8K reputation)SSCrazy Eights (8K reputation)SSCrazy Eights (8K reputation)SSCrazy Eights (8K reputation)SSCrazy Eights (8K reputation)SSCrazy Eights (8K reputation)SSCrazy Eights (8K reputation)

Group: General Forum Members
Points: 8006 Visits: 7162
sp_MSforeachdb is indeed a cursor, and not a particularly good one.

Still, it exists, and it's useful for quick-and-dirty tasks sometimes, particularly if you don't have a lot of dbs.

So, I'll offer a version for it:



CREATE TABLE #t_nodb (
dbname nvarchar(128)
)

EXEC sp_MSforeachdb '
IF ''?'' IN (''tempDB'') -- IN (''master'', ''model'', ''msdb'', ''tempdb'')
RETURN
INSERT INTO #t_nodb
SELECT ''?''
WHERE
NOT EXISTS(SELECT 1 FROM [?].sys.extended_properties)
'

SELECT *
FROM #t_nodb
ORDER BY dbname

DROP TABLE #t_nodb




SQL DBA,SQL Server MVP(07, 08, 09)[size=2]Prosecutor James Blackburn, in closing argument in the Fatal Vision murders trial: If in the future, you should cry a tear, cry one for them [the murder victims]. If in the future, you should say a prayer, say one for them. And if in the future, you should light a candle, light one for them.[/size]
seraph67
seraph67
Forum Newbie
Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)

Group: General Forum Members
Points: 3 Visits: 69
Sean - That works, thank you very much.

OldHand, SSCertifiable and Ten Centuries, thanks for the tips.
Sean Lange
Sean Lange
One Orange Chip
One Orange Chip (26K reputation)One Orange Chip (26K reputation)One Orange Chip (26K reputation)One Orange Chip (26K reputation)One Orange Chip (26K reputation)One Orange Chip (26K reputation)One Orange Chip (26K reputation)One Orange Chip (26K reputation)

Group: General Forum Members
Points: 26366 Visits: 17557
seraph67 (4/1/2013)
Sean - That works, thank you very much.

OldHand, SSCertifiable and Ten Centuries, thanks for the tips.


You're welcome. Glad that works for you.

BTW, you copied everybody's ranking and not their names. ;-)

_______________________________________________________________

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)
seraph67
seraph67
Forum Newbie
Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)

Group: General Forum Members
Points: 3 Visits: 69
My bad =D

Again, thanks for the help, all. Smile

FYI - Here's the final product, works well; just in case it can help someone else.

declare @SQL nvarchar(max)
select @SQL = 'declare @MyQuery nvarchar(max) =
(select ''select count(*) as PropertyCount, '''''' + name + '''''' as DBName from '' + name + ''.sys.extended_properties union all ''
from sys.databases
where name not in (''master'', ''tempDB'', ''model'',''msdb'', ''ReportServer'', ''ReportServerTempDB'', ''rx'')
for xml path(''''))
set @MyQuery = ''select DBName from ('' + left(@MyQuery, len(@MyQuery) - 10) + '' )x where x.PropertyCount = 0 order by DBName''
exec sp_executesql @MyQuery'
execute (@SQL)


Lynn Pettis
Lynn Pettis
SSC-Forever
SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)

Group: General Forum Members
Points: 40000 Visits: 38564
ScottPletcher (3/26/2013)
sp_MSforeachdb is indeed a cursor, and not a particularly good one.

Still, it exists, and it's useful for quick-and-dirty tasks sometimes, particularly if you don't have a lot of dbs.

...


And has the dubious honor of being an undocumented procedure as well.

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