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

Query - Please Help! Expand / Collapse
Author
Message
Posted Tuesday, March 26, 2013 10:21 AM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Wednesday, June 19, 2013 10:26 AM
Points: 3, Visits: 67
Someone please tell me what I'm doing wrong.....

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!
Post #1435603
Posted Tuesday, March 26, 2013 11:38 AM
Mr or Mrs. 500

Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500

Group: General Forum Members
Last Login: Friday, July 18, 2014 3:36 PM
Points: 541, Visits: 1,044
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

Post #1435641
Posted Tuesday, March 26, 2013 12:53 PM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Yesterday @ 3:21 PM
Points: 13,083, Visits: 11,918
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 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 #1435659
Posted Tuesday, March 26, 2013 3:33 PM
Mr or Mrs. 500

Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500

Group: General Forum Members
Last Login: Friday, July 18, 2014 3:36 PM
Points: 541, Visits: 1,044
Nicely done, Sean.
Post #1435701
Posted Tuesday, March 26, 2013 4:25 PM
SSCommitted

SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

Group: General Forum Members
Last Login: Yesterday @ 3:51 PM
Points: 1,967, Visits: 2,905
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)
"In America, every man is innocent until proven broke!" Brant Parker
Post #1435708
Posted Monday, April 1, 2013 6:31 AM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Wednesday, June 19, 2013 10:26 AM
Points: 3, Visits: 67
Sean - That works, thank you very much.

OldHand, SSCertifiable and Ten Centuries, thanks for the tips.
Post #1437419
Posted Monday, April 1, 2013 7:45 AM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Yesterday @ 3:21 PM
Points: 13,083, Visits: 11,918
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 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 #1437435
Posted Monday, April 1, 2013 9:39 AM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Wednesday, June 19, 2013 10:26 AM
Points: 3, Visits: 67
My bad =D

Again, thanks for the help, all. :)

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)

Post #1437504
Posted Monday, April 1, 2013 10:33 AM


SSC-Insane

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

Group: General Forum Members
Last Login: Yesterday @ 8:42 PM
Points: 23,009, Visits: 31,510
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.



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

Add to briefcase

Permissions Expand / Collapse