Cursor - passing @dbname to INSERT STATEMENT

  • I have a cursor that grabs all the database names and then needs to select data from the dbname.dbo.sysfiles table to insert into a DBGrowth table. The issue is that some of the Sharepoint database name have the (-) char so I need to concatenate '[' with the @dbname value from cursor to create the name of the table that will be used in thr FROM clause.

    Here's the cursor code thus far. Any assistance woul be most appreciated.

    DECLARE getDBName CURSOR FOR

    select name from sys.databases

    OPEN getDBName

    DECLARE @dbname varchar(101)

    DECLARE @dbsys varchar(101)

    FETCH NEXT FROM getDBName INTO @dbname

    SET @dbsys = '[' + @dbname + '.dbo.sysfiles]'

    WHILE @@FETCH_STATUS = 0

    BEGIN

    INSERT TEMPDB.dbo.DBGROWTH

    SELECT @@servername, @dbname, getDate()

    FROM @dbsys

    FETCH NEXT FROM getDBName INTO @dbname

    END

    CLOSE getDBName

    DEALLOCATE getDBName

  • Even though I do not like the cursor, I don't think there could be another way since you are trying to do some dynamic SQL There. Here's a solution, I've tried it, you can add the fields you want from the sysfiles table in the table, and it will refresh everytime.

    USE tempdb

    GO

    DECLARE getDBName CURSOR FOR

    SELECT name

    FROM sys.databases

    OPEN getDBName

    DECLARE @dbname VARCHAR(101)

    DECLARE @dbsys VARCHAR(101)

    DECLARE @SQL NVARCHAR(2000)

    IF EXISTS (SELECT *

    FROM sys.objects

    WHERE object_id = OBJECT_ID(N'[dbo].[DBGrowth]')

    AND TYPE IN (N'U'))

    DROP TABLE [dbo].[DBGrowth]

    CREATE TABLE DBGrowth (

    ServerName NVARCHAR(128),

    DbName NVARCHAR(128),

    NVARCHAR(128),

    [MaxSize] NVARCHAR(128),

    [growth] NVARCHAR(128),

    DATE DATETIME)

    FETCH NEXT FROM getDBName

    INTO @dbname

    WHILE @@FETCH_STATUS = 0

    BEGIN

    SET @dbsys = '['

    + @dbname

    + '].dbo.sysfiles'

    SET @SQL = ('INSERT TEMPDB.dbo.DBGROWTH '

    + ' SELECT @@SERVERNAME, '''

    + @dbname

    + ''',size, maxsize, growth, getDate() '

    + ' FROM '

    + @DbSys)

    PRINT @SQL

    EXEC sp_executeSQL

    @SQL

    FETCH NEXT FROM getDBName

    INTO @dbname

    END

    CLOSE getDBName

    DEALLOCATE getDBName

    SELECT *

    FROM DBGrowth

    Hope it helps,

    Cheers,

    J-F

    Cheers,

    J-F

  • Thank-you JF. Using dynamic SQL did the trick. Happy New Year. 🙂

  • Another way, no cursor but still not amazing.

    declare @sql varchar(MAX)

    set @sql = ''

    create TABLE #temp (ID INT IDENTITY (1,1) PRIMARY KEY CLUSTERED, ServerName sysname, DBName sysname, Size int, ReadingDate datetime)

    select @sql = @sql + 'INSERT INTO #temp (ServerName, DBName, Size, ReadingDate) select @@ServerName, ''' + name + ''', Size, GETDATE() from [' + name + '].[dbo].[sysfiles];'

    from master.sys.databases

    EXEC (@sql)

    SELECT * FROM #temp

    Atlantis Interactive - SQL Server Tools
    My blog[/url]
    Why I wrote a sql query analyzer clone

  • Nice, I have to say I prefer this one a thousand times, since there is no cursor. I did not know you could append in a string from a multirow query. Great job!

    Cheers,

    J-F

    Cheers,

    J-F

  • Yet another way, using Matt's example to build on.

    create TABLE #temp (ID INT IDENTITY (1,1) PRIMARY KEY CLUSTERED, ServerName sysname, DBName sysname, Size int, ReadingDate datetime)

    EXEC sp_MSforeachdb ' USE ?

    INSERT INTO #temp (ServerName, DBName, Size, ReadingDate)

    SELECT @@ServerName as ServerName,

    Name,

    Size,

    GETDATE() as ReadingDate

    FROM sys.database_files'

    SELECT * FROM #temp

    drop table #temp

    John Rowan

    ======================================================
    ======================================================
    Forum Etiquette: How to post data/code on a forum to get the best help[/url] - by Jeff Moden

  • Isn't this feature deprecated? I thought I read not to use this somewhere, maybe my memory had gone wacko, but I prefer to do this in a select, then using a deprecated feature.

    Cheers,

    J-F

    Cheers,

    J-F

  • I am not aware of it being depricated. It exists in SQL Server 2008 as well.

    John Rowan

    ======================================================
    ======================================================
    Forum Etiquette: How to post data/code on a forum to get the best help[/url] - by Jeff Moden

  • John Rowan (1/9/2009)


    I am not aware of it being depricated. It exists in SQL Server 2008 as well.

    It's not deprecated, but it is a cursor under the hood. AFAIK.

    You can script sp_ stored procedures if you use SMO, or another IDE.

    Atlantis Interactive - SQL Server Tools
    My blog[/url]
    Why I wrote a sql query analyzer clone

  • Yep. Many of the interworkings of SQL Server are cursors under the hood. This just beats writing one and works fine for admin tasks.

    John Rowan

    ======================================================
    ======================================================
    Forum Etiquette: How to post data/code on a forum to get the best help[/url] - by Jeff Moden

Viewing 10 posts - 1 through 9 (of 9 total)

You must be logged in to reply to this topic. Login to reply