January 24, 2011 at 10:17 pm
Hi , i have blelow code and @command has string value and i want to assign Select @Dbnames = '+ @Dbname+'
in below code where @Dbname is variable but seems like some syntax issue with the string , can any body please help here?
EXEC @ReturnCode = msdb.dbo.sp_add_jobstep @job_name=@JobName, @step_name=N'Weekly Online Index Maintenance',
@step_id=1,
@cmdexec_success_code=0,
@on_success_action=3,
@on_success_step_id=2,
@on_fail_action=2,
@on_fail_step_id=0,
@retry_attempts=0,
@retry_interval=0,
@os_run_priority=0, @subsystem=N'TSQL',
@command=N'Declare
@ObjName Varchar(255) ,
@indexname varchar(255),
@Dbnames Varchar(255),
@Db_id varchar(255),
@Tab_id int,
@Fragmentation int,@Pages int
Select @Pages=10000
Select @Fragmentation=30
Select @Dbnames = '+ @Dbname+'
--set @dbname=''test''
set @db_id=db_id(@dbname)
if exists (
Select name
From sys.databases D
Where state = 0 --online
And name Not In (''master'', ''tempdb'', ''msdb'', ''model'')
-- If is not null, database is a database snapshot
And source_database_id Is Null
And name = @DBName
)
January 24, 2011 at 10:57 pm
You cannot concatenate variables in parameters ; concatenate the data as a single variable using this SET @Variable = 'some data' + @DBNAME + 'remaining data' and then pass the @Variable to the SP as a parameter..
January 24, 2011 at 11:36 pm
Thanks for reply , this is not the sp , what i am trying to do is to create generic sql script that will create job for each user db where ever sql server i run this , so the issue now is , when i run this on sql server i need db name so after creating the job , the t-sql in the job can run against the db which is part of below statement @command= , i could able to get the @dbname when job is created but the t-sql of the step need db name to run against and there is what i need @dbname to assign the db in the job step once job is created, so not sure how i can assign @dbname with below statement Select @Dbnames = +@dbname, could you please elaborate the soln you are proposing?
/****** Object: Step [Weekly Online Index Maintenance] Script Date: 01/22/2011 16:54:18 ******/
EXEC @ReturnCode = msdb.dbo.sp_add_jobstep @job_name=@JobName, @step_name=N'Weekly Online Index Maintenance',
@step_id=1,
@cmdexec_success_code=0,
@on_success_action=3,
@on_success_step_id=2,
@on_fail_action=2,
@on_fail_step_id=0,
@retry_attempts=0,
@retry_interval=0,
@os_run_priority=0, @subsystem=N'TSQL',
@command='Declare
@ObjName Varchar(255) ,
@indexname varchar(255),
@Dbnames Varchar(255),
@Db_id varchar(255),
@Tab_id int,
@Fragmentation int,@Pages int
Select @Pages=10000
Select @Fragmentation=30
Select @Dbnames = +@dbname
set @db_id=db_id(@dbname)
if exists (
Select name
From sys.databases D
Where state = 0 --online
And name Not In (''master'', ''tempdb'', ''msdb'', ''model'')
-- If is not null, database is a database snapshot
And source_database_id Is Null
And name = @DBNames
)
January 24, 2011 at 11:40 pm
just to add this is the code after job is created , so if i could assign the db name so it would be Select @Dbnames = 'reporting' not like Select @Dbnames = ''+@Dbname+''
as below...
Declare
@ObjName Varchar(255) ,
@indexname varchar(255),
@Dbnames Varchar(255),
@Db_id varchar(255),
@Tab_id int,
@Fragmentation int,@Pages int
Select @Pages=10000
Select @Fragmentation=30
Select @Dbnames = ''+@Dbname+''
--set @dbname='test'
set @db_id=db_id(@dbname)
if exists (
Select name
From sys.databases D
Where state = 0 --online
And name Not In ('master', 'tempdb', 'msdb', 'model')
-- If is not null, database is a database snapshot
And source_database_id Is Null
And name = @DBName
)
January 25, 2011 at 2:16 am
How about this?
DECLARE @Command NVARCHAR(MAX)
DECLARE @DBName NVARCHAR(128)
SELECT @DBName = DB_NAME()
SELECT @Command = N'Declare
@ObjName Varchar(255) ,
@indexname varchar(255),
@Dbnames Varchar(255),
@Db_id varchar(255),
@Tab_id int,
@Fragmentation int,@Pages int
Select @Pages=10000
Select @Fragmentation=30
Select @Dbnames = '''+ @DBName+'''
--set @dbname=''test''
set @db_id=db_id(@dbname)
if exists (
Select name
From sys.databases D
Where state = 0 --online
And name Not In (''master'', ''tempdb'', ''msdb'', ''model'')
-- If is not null, database is a database snapshot
And source_database_id Is Null
And name = @DBName
)
January 25, 2011 at 8:13 am
thanks but it still gives incorrect syntax at Select @Dbnames = '''+ @DBName+'''
here is the full script to create jobs
Declare @CurrID int,@MaxID int
Declare @dbs Table (DBID int identity(1, 1) not null primary key,
DBName sysname not null)
--set @CurrID=0
Declare @DBName as sysname
DECLARE @ReturnCode INT
DECLARE @jobId BINARY(16)
Declare @JobName as Varchar(500)
Insert Into @dbs (DBName)
Select name
From sys.databases
Where database_id >=5
Select @MaxID = Max(DBID), @CurrID = 1
From @dbs;
While @CurrID <= @MaxID
Begin
select @DBName = DBName from @dbs where DBID=@CurrID
/****** Object: Job [OSSG- Weekly Online Index Rebuild-test] Script Date: 01/22/2011 16:54:18 ******/
BEGIN TRANSACTION
SELECT @ReturnCode = 0
/****** Object: JobCategory [Database Maintenance] Script Date: 01/22/2011 16:54:18 ******/
IF NOT EXISTS (SELECT name FROM msdb.dbo.syscategories WHERE name=N'Database Maintenance' AND category_class=1)
BEGIN
EXEC @ReturnCode = msdb.dbo.sp_add_category @class=N'JOB', @type=N'LOCAL', @name=N'Database Maintenance'
IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
END
Select @JobName='SMC- Weekly Online Index Rebuild - ' +@DBName
IF EXISTS (SELECT job_id FROM msdb.dbo.sysjobs_view WHERE name = @JobName)
EXEC msdb.dbo.sp_delete_job @job_name=@JobName
EXEC @ReturnCode = msdb.dbo.sp_add_job @job_name=@JobName ,
@enabled=1,
@notify_level_eventlog=2,
@notify_level_email=0,
@notify_level_netsend=0,
@notify_level_page=0,
@delete_level=0,
@description=N'No description available.',
@category_name=N'Database Maintenance',
@owner_login_name=N'sa'
--IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
/****** Object: Step [Weekly Online Index Maintenance] Script Date: 01/22/2011 16:54:18 ******/
EXEC @ReturnCode = msdb.dbo.sp_add_jobstep @job_name=@JobName, @step_name=N'Weekly Online Index Maintenance',
@step_id=1,
@cmdexec_success_code=0,
@on_success_action=3,
@on_success_step_id=2,
@on_fail_action=2,
@on_fail_step_id=0,
@retry_attempts=0,
@retry_interval=0,
@os_run_priority=0, @subsystem=N'TSQL',
@command='Declare
@ObjName Varchar(255) ,
@indexname varchar(255),
@Dbnames Varchar(255),
@Db_id varchar(255),
@Tab_id int,
@Fragmentation int,@Pages int
Select @Pages=10000
Select @Fragmentation=30
Select @Dbnames = '''+ @DBName+'''
--set @dbname=''test''
set @db_id=db_id(@dbname)
if exists (
Select name
From sys.databases D
Where state = 0 --online
And name Not In (''master'', ''tempdb'', ''msdb'', ''model'')
-- If is not null, database is a database snapshot
And source_database_id Is Null
And name = @DBNames
)
Begin
Exec(''Declare CheckTab Cursor For SELECT distinct it.table_name,si.name FROM information_schema.columns ic
join
information_schema.tables it
on ic.table_name =it.table_name
join sys.indexes si
on object_id(ic.table_name)=si.object_id
join sys.dm_db_index_physical_stats(''+ @db_id +'', NULL, NULL, NULL, NULL) indexstats
ON si.OBJECT_ID = indexstats.OBJECT_ID
AND si.index_id = indexstats.index_id
WHERE indexstats.avg_fragmentation_in_percent > @Fragmentation
and indexstats.page_count >=@Pages
and si.Name is not NULL
and it.table_name not in
(select table_name from information_schema.columns where data_type in (''''image'''', ''''text'''', ''''ntext'''', ''''varchar(max)'''', ''''nvarchar(max)'''', ''''varbinary(max)'''', ''''xml'''' ))
and it.table_type=''''BASE TABLE'''''')
Open CheckTab
Fetch Next from CheckTab into @ObjName ,@indexname
While (@@Fetch_Status=0)
Begin
Exec(''Use [''+@DBName+''] ALTER INDEX ''+@indexname +'' ON ''+@ObjName+'' REBUILD with (Online = ON)'')
Fetch Next from CheckTab into @ObjName ,@indexname
End
Close CheckTab
Deallocate CheckTab
End
',
@database_name=@DBName,
@flags=0
IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
/****** Object: Step [Update Statistics] Script Date: 01/24/2011 15:58:49 ******/
EXEC @ReturnCode = msdb.dbo.sp_add_jobstep @job_name=@jobname, @step_name=N'Update Statistics',
@step_id=2,
@cmdexec_success_code=0,
@on_success_action=1,
@on_success_step_id=0,
@on_fail_action=2,
@on_fail_step_id=0,
@retry_attempts=0,
@retry_interval=0,
@os_run_priority=0, @subsystem=N'TSQL',
@command= 'EXEC sp_updatestats',
@database_name=@DBName,
@flags=0
IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
EXEC @ReturnCode = msdb.dbo.sp_update_job @job_name = @JobName, @start_step_id = 1
IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
EXEC @ReturnCode = msdb.dbo.sp_add_jobschedule @job_name=@JobName, @name=N'Saturday 04:00 AM',
@enabled=1,
@freq_type=8,
@freq_interval=64,
@freq_subday_type=1,
@freq_subday_interval=0,
@freq_relative_interval=0,
@freq_recurrence_factor=1,
@active_start_date=20090624,
@active_end_date=99991231,
@active_start_time=40000,
@active_end_time=235959
IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
EXEC @ReturnCode = msdb.dbo.sp_add_jobserver @job_name = @JobName, @server_name = N'(local)'
IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
COMMIT TRANSACTION
GOTO EndSave
QuitWithRollback:
IF (@@TRANCOUNT > 0) ROLLBACK TRANSACTION
EndSave:
select @CurrID=@CurrID+1
End
January 25, 2011 at 9:24 am
Try this out (the code i added/edited has been wrapped around /* START OF ADDITION */ and /* END OF ADDITION */)
Declare @CurrID int,@MaxID int
Declare @dbs Table (DBID int identity(1, 1) not null primary key,
DBName sysname not null)
--set @CurrID=0
Declare @DBName as sysname
DECLARE @ReturnCode INT
DECLARE @jobId BINARY(16)
Declare @JobName as Varchar(500)
Insert Into @dbs (DBName)
Select name
From sys.databases
Where database_id >=5
Select @MaxID = Max(DBID), @CurrID = 1
From @dbs;
/* START OF ADDITION */
DECLARE @Command NVARCHAR(MAX)
SET @Command = ''
/* END OF ADDITION */
While @CurrID <= @MaxID
Begin
select @DBName = DBName from @dbs where DBID=@CurrID
/* START OF ADDITION */
SET @Command = ''
IF @Command IS NOT NULL
BEGIN
SELECT @Command = 'Declare
@ObjName Varchar(255) ,
@indexname varchar(255),
@Dbnames Varchar(255),
@Db_id varchar(255),
@Tab_id int,
@Fragmentation int,@Pages int
Select @Pages=10000
Select @Fragmentation=30
Select @Dbnames = '''+ @DBName+'''
--set @dbname=''test''
set @db_id=db_id(@dbname)
if exists (
Select name
From sys.databases D
Where state = 0 --online
And name Not In (''master'', ''tempdb'', ''msdb'', ''model'')
-- If is not null, database is a database snapshot
And source_database_id Is Null
And name = @DBNames
)
Begin
Exec(''Declare CheckTab Cursor For SELECT distinct it.table_name,si.name FROM information_schema.columns ic join
information_schema.tables it
on ic.table_name =it.table_name
join sys.indexes si
on object_id(ic.table_name)=si.object_id
join sys.dm_db_index_physical_stats(''+ @db_id +'', NULL, NULL, NULL, NULL) indexstats
ON si.OBJECT_ID = indexstats.OBJECT_ID
AND si.index_id = indexstats.index_id
WHERE indexstats.avg_fragmentation_in_percent > @Fragmentation
and indexstats.page_count >=@Pages
and si.Name is not NULL
and it.table_name not in
(select table_name from information_schema.columns where data_type in (''''image'''', ''''text'''', ''''ntext'''', ''''varchar(max)'''', ''''nvarchar(max)'''', ''''varbinary(max)'''', ''''xml'''' ))
and it.table_type=''''BASE TABLE'''''')
Open CheckTab
Fetch Next from CheckTab into @ObjName ,@indexname
While (@@Fetch_Status=0)
Begin
Exec(''Use [''+@DBName+''] ALTER INDEX ''+@indexname +'' ON ''+@ObjName+'' REBUILD with (Online = ON)'')
Fetch Next from CheckTab into @ObjName ,@indexname
End
Close CheckTab
Deallocate CheckTab
End
'
END
/* END OF ADDITION */
/****** Object: Job [OSSG- Weekly Online Index Rebuild-test] Script Date: 01/22/2011 16:54:18 ******/
BEGIN TRANSACTION
SELECT @ReturnCode = 0
/****** Object: JobCategory [Database Maintenance] Script Date: 01/22/2011 16:54:18 ******/
IF NOT EXISTS (SELECT name FROM msdb.dbo.syscategories WHERE name=N'Database Maintenance' AND category_class=1)
BEGIN
EXEC @ReturnCode = msdb.dbo.sp_add_category @class=N'JOB', @type=N'LOCAL', @name=N'Database Maintenance'
IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
END
Select @JobName='SMC- Weekly Online Index Rebuild - ' +@DBName
IF EXISTS (SELECT job_id FROM msdb.dbo.sysjobs_view WHERE name = @JobName)
EXEC msdb.dbo.sp_delete_job @job_name=@JobName
EXEC @ReturnCode = msdb.dbo.sp_add_job @job_name=@JobName ,
@enabled=1,
@notify_level_eventlog=2,
@notify_level_email=0,
@notify_level_netsend=0,
@notify_level_page=0,
@delete_level=0,
@description=N'No description available.',
@category_name=N'Database Maintenance',
@owner_login_name=N'sa'
--IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
/****** Object: Step [Weekly Online Index Maintenance] Script Date: 01/22/2011 16:54:18 ******/
EXEC @ReturnCode = msdb.dbo.sp_add_jobstep @job_name=@JobName, @step_name=N'Weekly Online Index Maintenance',
@step_id=1,
@cmdexec_success_code=0,
@on_success_action=3,
@on_success_step_id=2,
@on_fail_action=2,
@on_fail_step_id=0,
@retry_attempts=0,
@retry_interval=0,
@os_run_priority=0, @subsystem=N'TSQL',
/* START OF ADDITION */
@command=@Command,
/* END OF ADDITION */
@database_name=@DBName,
@flags=0
IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
/****** Object: Step [Update Statistics] Script Date: 01/24/2011 15:58:49 ******/
EXEC @ReturnCode = msdb.dbo.sp_add_jobstep @job_name=@jobname, @step_name=N'Update Statistics',
@step_id=2,
@cmdexec_success_code=0,
@on_success_action=1,
@on_success_step_id=0,
@on_fail_action=2,
@on_fail_step_id=0,
@retry_attempts=0,
@retry_interval=0,
@os_run_priority=0, @subsystem=N'TSQL',
@command= 'EXEC sp_updatestats',
@database_name=@DBName,
@flags=0
IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
EXEC @ReturnCode = msdb.dbo.sp_update_job @job_name = @JobName, @start_step_id = 1
IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
EXEC @ReturnCode = msdb.dbo.sp_add_jobschedule @job_name=@JobName, @name=N'Saturday 04:00 AM',
@enabled=1,
@freq_type=8,
@freq_interval=64,
@freq_subday_type=1,
@freq_subday_interval=0,
@freq_relative_interval=0,
@freq_recurrence_factor=1,
@active_start_date=20090624,
@active_end_date=99991231,
@active_start_time=40000,
@active_end_time=235959
IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
EXEC @ReturnCode = msdb.dbo.sp_add_jobserver @job_name = @JobName, @server_name = N'(local)'
IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
COMMIT TRANSACTION
GOTO EndSave
QuitWithRollback:
IF (@@TRANCOUNT > 0) ROLLBACK TRANSACTION
EndSave:
select @CurrID=@CurrID+1
End
{Edit : Added details about my additions to the SP}
January 25, 2011 at 11:56 am
perfect , much appreciated!!
Viewing 8 posts - 1 through 7 (of 7 total)
You must be logged in to reply to this topic. Login to reply