Click here to monitor SSC
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Cursor - passing @dbname to INSERT STATEMENT


Cursor - passing @dbname to INSERT STATEMENT

Author
Message
d2_stevenson
d2_stevenson
Grasshopper
Grasshopper (13 reputation)Grasshopper (13 reputation)Grasshopper (13 reputation)Grasshopper (13 reputation)Grasshopper (13 reputation)Grasshopper (13 reputation)Grasshopper (13 reputation)Grasshopper (13 reputation)

Group: General Forum Members
Points: 13 Visits: 185
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
J-F Bergeron
J-F Bergeron
Right there with Babe
Right there with Babe (785 reputation)Right there with Babe (785 reputation)Right there with Babe (785 reputation)Right there with Babe (785 reputation)Right there with Babe (785 reputation)Right there with Babe (785 reputation)Right there with Babe (785 reputation)Right there with Babe (785 reputation)

Group: General Forum Members
Points: 785 Visits: 2707
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),
[size] 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
d2_stevenson
d2_stevenson
Grasshopper
Grasshopper (13 reputation)Grasshopper (13 reputation)Grasshopper (13 reputation)Grasshopper (13 reputation)Grasshopper (13 reputation)Grasshopper (13 reputation)Grasshopper (13 reputation)Grasshopper (13 reputation)

Group: General Forum Members
Points: 13 Visits: 185
Thank-you JF. Using dynamic SQL did the trick. Happy New Year. :-)
Matt Whitfield
Matt Whitfield
Mr or Mrs. 500
Mr or Mrs. 500 (547 reputation)Mr or Mrs. 500 (547 reputation)Mr or Mrs. 500 (547 reputation)Mr or Mrs. 500 (547 reputation)Mr or Mrs. 500 (547 reputation)Mr or Mrs. 500 (547 reputation)Mr or Mrs. 500 (547 reputation)Mr or Mrs. 500 (547 reputation)

Group: General Forum Members
Points: 547 Visits: 719
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
Why I wrote a sql query analyzer clone
J-F Bergeron
J-F Bergeron
Right there with Babe
Right there with Babe (785 reputation)Right there with Babe (785 reputation)Right there with Babe (785 reputation)Right there with Babe (785 reputation)Right there with Babe (785 reputation)Right there with Babe (785 reputation)Right there with Babe (785 reputation)Right there with Babe (785 reputation)

Group: General Forum Members
Points: 785 Visits: 2707
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
John Rowan
John Rowan
SSCarpal Tunnel
SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)

Group: General Forum Members
Points: 4488 Visits: 4530
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 - by Jeff Moden
J-F Bergeron
J-F Bergeron
Right there with Babe
Right there with Babe (785 reputation)Right there with Babe (785 reputation)Right there with Babe (785 reputation)Right there with Babe (785 reputation)Right there with Babe (785 reputation)Right there with Babe (785 reputation)Right there with Babe (785 reputation)Right there with Babe (785 reputation)

Group: General Forum Members
Points: 785 Visits: 2707
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
John Rowan
John Rowan
SSCarpal Tunnel
SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)

Group: General Forum Members
Points: 4488 Visits: 4530
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 - by Jeff Moden
Matt Whitfield
Matt Whitfield
Mr or Mrs. 500
Mr or Mrs. 500 (547 reputation)Mr or Mrs. 500 (547 reputation)Mr or Mrs. 500 (547 reputation)Mr or Mrs. 500 (547 reputation)Mr or Mrs. 500 (547 reputation)Mr or Mrs. 500 (547 reputation)Mr or Mrs. 500 (547 reputation)Mr or Mrs. 500 (547 reputation)

Group: General Forum Members
Points: 547 Visits: 719
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
Why I wrote a sql query analyzer clone
John Rowan
John Rowan
SSCarpal Tunnel
SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)

Group: General Forum Members
Points: 4488 Visits: 4530
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 - by Jeff Moden
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