runjob.sql 3.2 KB

12345678910111213141516171819202122232425262728293031323334353637383940414243444546474849505152535455565758596061626364656667686970717273747576777879808182838485868788899091
  1. -- 1. create job
  2. -- Details in: http://msdn.microsoft.com/en-us/library/ms182079.aspx
  3. USE msdb
  4. EXEC sp_add_job @job_name = N'snRebuildIndexes',
  5. @enabled = 1,
  6. @description = N'Rebuild indexes for SecretNet database',
  7. @notify_level_eventlog = 2,
  8. @notify_level_netsend =2, -- notify on failure
  9. @notify_level_page = 2 -- notify on failure
  10. go
  11. -- 2.
  12. USE msdb
  13. EXEC sp_add_jobserver @job_name = 'snRebuildIndexes' -- , @server_name = N'ws702z'
  14. go
  15. -- 3.
  16. USE msdb
  17. EXEC sp_add_jobstep @job_name = N'snRebuildIndexes',
  18. @step_name = N'Rebuild SecretNet indexes',
  19. @subsystem = N'TSQL',
  20. @on_success_action = 1, -- exit
  21. @retry_attempts = 5, -- number of retry attempts
  22. @retry_interval = 5, -- interval to next attempt in minutes
  23. -- @database_name=N'SN7_SERVER_SCHEMA',
  24. @command = N'begin \
  25. declare @databaseName sysname = N''SN7_SERVER_SCHEMA''; \
  26. declare @rebuildFloor float = 40; \
  27. \
  28. declare @schemaName sysname; \
  29. declare @tableName sysname; \
  30. declare @indexName sysname; \
  31. declare @fragmentation float; \
  32. \
  33. declare @command nvarchar(500); \
  34. \
  35. declare indexCursor cursor fast_forward local for \
  36. select s.name schema_name, t.name table_name, i.name index_name, d.avg_fragmentation_in_percent fragmentation \
  37. from sys.dm_db_index_physical_stats( DB_ID(@databaseName), null, null, null, null) d \
  38. inner join sys.tables t on d.object_id = t.object_id \
  39. inner join sys.schemas s on t.schema_id = s.schema_id \
  40. inner join sys.indexes i on d.object_id = i.object_id AND d.index_id = i.index_id \
  41. where d.index_id > 0 \
  42. and d.avg_fragmentation_in_percent > 10 \
  43. and d.page_count > 8 \
  44. \
  45. open indexCursor; \
  46. \
  47. while( 1=1 ) \
  48. begin \
  49. fetch next from indexCursor into @schemaName, @tableName, @indexName, @fragmentation; \
  50. if @@FETCH_STATUS <> 0 break; \
  51. \
  52. begin try \
  53. set @command = N''ALTER INDEX '' + @indexName + N'' ON '' + @databaseName + N''.'' + @schemaName + N''.'' + @tableName; \
  54. if @fragmentation < @rebuildFloor \
  55. begin \
  56. set @command = @command + N'' REORGANIZE;''; \
  57. set @command = @command + N'' UPDATE STATISTICS '' + @databaseName + N''.'' + @schemaName + N''.'' + @tableName + N'' '' + @indexName + N'';''; \
  58. end \
  59. else \
  60. begin \
  61. set @command = @command + N'' REBUILD WITH (ONLINE = ON); ''; \
  62. end; \
  63. \
  64. exec (@command); \
  65. end try \
  66. begin catch \
  67. continue; \
  68. end catch \
  69. end; \
  70. close indexCursor; \
  71. deallocate indexCursor; \
  72. end;'
  73. GO
  74. -- 6.1. set job schedule
  75. -- details in http://msdn.microsoft.com/en-us/library/ms187358.aspx
  76. USE msdb
  77. EXEC sp_add_jobschedule @job_name = N'snRebuildIndexes',
  78. @name = N'ScheduledSecretNetRebuildIndexes',
  79. @freq_type = 4, --daily
  80. @freq_interval = 1, --once
  81. @active_start_time = '000100' -- (00:01) 24hr HHMMSS.
  82. go
  83. -- 6.2. start immediately
  84. --USE msdb
  85. --EXEC sp_start_job @job_name = N'snRebuildIndexes'