[6267] | 1 | USE [HeuristicLab.Hive-3.4]
|
---|
[4629] | 2 | /* this script is supposed to be executed after the plain DB is generated by the linq-to-sql schema */
|
---|
| 3 |
|
---|
[5106] | 4 | /* use these DROP commands if you want to run this query a second time on the same db */
|
---|
| 5 |
|
---|
[4629] | 6 | /*
|
---|
| 7 | ALTER TABLE dbo.AssignedResources ALTER COLUMN AssignedRessourcesId DROP ROWGUIDCOL;
|
---|
| 8 | ALTER TABLE dbo.Job ALTER COLUMN JobId DROP ROWGUIDCOL;
|
---|
| 9 | ALTER TABLE dbo.SlaveGroup_Resource ALTER COLUMN SlaveGroup_RessourceId DROP ROWGUIDCOL;
|
---|
| 10 | ALTER TABLE dbo.Plugin ALTER COLUMN PluginId DROP ROWGUIDCOL;
|
---|
| 11 | ALTER TABLE dbo.RequiredPlugins ALTER COLUMN RequiredPluginId DROP ROWGUIDCOL;
|
---|
| 12 | ALTER TABLE dbo.Resource ALTER COLUMN ResourceId DROP ROWGUIDCOL;
|
---|
| 13 | ALTER TABLE dbo.UptimeCalendar ALTER COLUMN UptimeCalendarId DROP ROWGUIDCOL;
|
---|
| 14 | ALTER TABLE dbo.HiveExperiment ALTER COLUMN HiveExperimentId DROP ROWGUIDCOL;
|
---|
| 15 |
|
---|
| 16 | ALTER TABLE dbo.AssignedResources DROP CONSTRAINT [DF_AssignedResources_AssignedRessourcesId];
|
---|
| 17 | ALTER TABLE dbo.Job DROP CONSTRAINT [DF_Job_JobId];
|
---|
| 18 | ALTER TABLE dbo.SlaveGroup_Resource DROP CONSTRAINT [DF_SlaveGroup_ResourceSlaveGroup_RessourceId];
|
---|
| 19 | ALTER TABLE dbo.Plugin DROP CONSTRAINT [DF_Plugin_PluginId];
|
---|
| 20 | ALTER TABLE dbo.RequiredPlugins DROP CONSTRAINT [DF_RequiredPlugins_RequiredPluginId];
|
---|
| 21 | ALTER TABLE dbo.Resource DROP CONSTRAINT [DF_Resource_ResourceId];
|
---|
| 22 | ALTER TABLE dbo.UptimeCalendar DROP CONSTRAINT [DF_UptimeCalendar_UptimeCalendarId];
|
---|
| 23 | ALTER TABLE dbo.HiveExperiment DROP CONSTRAINT [DF_HiveExperiment_HiveExperimentId];
|
---|
| 24 | */
|
---|
| 25 |
|
---|
| 26 | ALTER TABLE dbo.AssignedResources ALTER COLUMN AssignedRessourcesId ADD ROWGUIDCOL;
|
---|
[6419] | 27 | ALTER TABLE dbo.AssignedResources WITH NOCHECK ADD CONSTRAINT [DF_AssignedResources_AssignedRessourcesId] DEFAULT (NEWSEQUENTIALID()) FOR AssignedRessourcesId;
|
---|
[4905] | 28 | ALTER TABLE [dbo].[AssignedResources] DROP CONSTRAINT [Job_AssignedResource]
|
---|
| 29 | ALTER TABLE [dbo].[AssignedResources] WITH CHECK ADD CONSTRAINT [Job_AssignedResource] FOREIGN KEY([JobId])
|
---|
| 30 | REFERENCES [dbo].[Job] ([JobId])
|
---|
| 31 | ON UPDATE CASCADE
|
---|
| 32 | ON DELETE CASCADE
|
---|
| 33 | GO
|
---|
| 34 | ALTER TABLE [dbo].[AssignedResources] DROP CONSTRAINT [Resource_AssignedResource]
|
---|
| 35 | ALTER TABLE [dbo].[AssignedResources] WITH CHECK ADD CONSTRAINT [Resource_AssignedResource] FOREIGN KEY([ResourceId])
|
---|
| 36 | REFERENCES [dbo].[Resource] ([ResourceId])
|
---|
| 37 | ON UPDATE CASCADE
|
---|
| 38 | ON DELETE CASCADE
|
---|
| 39 | GO
|
---|
[4629] | 40 |
|
---|
| 41 | ALTER TABLE dbo.Job ALTER COLUMN JobId ADD ROWGUIDCOL;
|
---|
[6419] | 42 | ALTER TABLE dbo.Job WITH NOCHECK ADD CONSTRAINT [DF_Job_JobId] DEFAULT (NEWSEQUENTIALID()) FOR JobId;
|
---|
[5511] | 43 | GO
|
---|
[4629] | 44 |
|
---|
[5511] | 45 | ALTER TABLE [dbo].[StateLog] DROP CONSTRAINT [Job_StateLog]
|
---|
| 46 | ALTER TABLE [dbo].[StateLog] WITH CHECK ADD CONSTRAINT [Job_StateLog] FOREIGN KEY([JobId])
|
---|
| 47 | REFERENCES [dbo].[Job] ([JobId])
|
---|
| 48 | ON UPDATE CASCADE
|
---|
| 49 | ON DELETE CASCADE
|
---|
| 50 | GO
|
---|
[5955] | 51 | ALTER TABLE [dbo].[StateLog] DROP CONSTRAINT [Resource_StateLog]
|
---|
| 52 | ALTER TABLE [dbo].[StateLog] WITH CHECK ADD CONSTRAINT [Resource_StateLog] FOREIGN KEY([SlaveId])
|
---|
| 53 | REFERENCES [dbo].[Resource] ([ResourceId])
|
---|
| 54 | ON UPDATE CASCADE
|
---|
| 55 | ON DELETE SET NULL
|
---|
| 56 | GO
|
---|
[5404] | 57 |
|
---|
[4629] | 58 | ALTER TABLE dbo.Plugin ALTER COLUMN PluginId ADD ROWGUIDCOL;
|
---|
[6419] | 59 | ALTER TABLE dbo.Plugin WITH NOCHECK ADD CONSTRAINT [DF_Plugin_PluginId] DEFAULT (NEWSEQUENTIALID()) FOR PluginId;
|
---|
[4629] | 60 |
|
---|
[5402] | 61 | ALTER TABLE dbo.PluginData ALTER COLUMN PluginDataId ADD ROWGUIDCOL;
|
---|
[6419] | 62 | ALTER TABLE dbo.PluginData WITH NOCHECK ADD CONSTRAINT [DF_PluginData_PluginDataId] DEFAULT (NEWSEQUENTIALID()) FOR PluginDataId;
|
---|
[5402] | 63 |
|
---|
[6033] | 64 | ALTER TABLE [dbo].[PluginData] DROP CONSTRAINT [Plugin_PluginData]
|
---|
| 65 | ALTER TABLE [dbo].[PluginData] WITH CHECK ADD CONSTRAINT [Plugin_PluginData] FOREIGN KEY([PluginId])
|
---|
| 66 | REFERENCES [dbo].[Plugin] ([PluginId])
|
---|
| 67 | ON UPDATE CASCADE
|
---|
| 68 | ON DELETE CASCADE
|
---|
| 69 | GO
|
---|
| 70 |
|
---|
[4629] | 71 | ALTER TABLE dbo.RequiredPlugins ALTER COLUMN RequiredPluginId ADD ROWGUIDCOL;
|
---|
[6419] | 72 | ALTER TABLE dbo.RequiredPlugins WITH NOCHECK ADD CONSTRAINT [DF_RequiredPlugins_RequiredPluginId] DEFAULT (NEWSEQUENTIALID()) FOR RequiredPluginId;
|
---|
[4629] | 73 |
|
---|
[4905] | 74 | ALTER TABLE [dbo].[RequiredPlugins] DROP CONSTRAINT [Job_RequiredPlugin]
|
---|
| 75 | ALTER TABLE [dbo].[RequiredPlugins] WITH CHECK ADD CONSTRAINT [Job_RequiredPlugin] FOREIGN KEY([JobId])
|
---|
| 76 | REFERENCES [dbo].[Job] ([JobId])
|
---|
| 77 | ON UPDATE CASCADE
|
---|
| 78 | ON DELETE CASCADE
|
---|
| 79 | GO
|
---|
| 80 |
|
---|
| 81 | ALTER TABLE [dbo].[RequiredPlugins] DROP CONSTRAINT [Plugin_RequiredPlugin]
|
---|
| 82 | ALTER TABLE [dbo].[RequiredPlugins] WITH CHECK ADD CONSTRAINT [Plugin_RequiredPlugin] FOREIGN KEY([PluginId])
|
---|
| 83 | REFERENCES [dbo].[Plugin] ([PluginId])
|
---|
| 84 | ON UPDATE CASCADE
|
---|
| 85 | ON DELETE CASCADE
|
---|
| 86 | GO
|
---|
| 87 |
|
---|
[4629] | 88 | ALTER TABLE dbo.Resource ALTER COLUMN ResourceId ADD ROWGUIDCOL;
|
---|
[6419] | 89 | ALTER TABLE dbo.Resource WITH NOCHECK ADD CONSTRAINT [DF_Resource_ResourceId] DEFAULT (NEWSEQUENTIALID()) FOR ResourceId;
|
---|
[4629] | 90 |
|
---|
| 91 | ALTER TABLE dbo.UptimeCalendar ALTER COLUMN UptimeCalendarId ADD ROWGUIDCOL;
|
---|
[6419] | 92 | ALTER TABLE dbo.UptimeCalendar WITH NOCHECK ADD CONSTRAINT [DF_UptimeCalendar_UptimeCalendarId] DEFAULT (NEWSEQUENTIALID()) FOR UptimeCalendarId;
|
---|
[4629] | 93 |
|
---|
| 94 | ALTER TABLE dbo.HiveExperiment ALTER COLUMN HiveExperimentId ADD ROWGUIDCOL;
|
---|
[6419] | 95 | ALTER TABLE dbo.HiveExperiment WITH NOCHECK ADD CONSTRAINT [DF_HiveExperiment_HiveExperimentId] DEFAULT (NEWSEQUENTIALID()) FOR HiveExperimentId;
|
---|
[4629] | 96 |
|
---|
[5511] | 97 | ALTER TABLE dbo.StateLog ALTER COLUMN StateLogId ADD ROWGUIDCOL;
|
---|
[6419] | 98 | ALTER TABLE dbo.StateLog WITH NOCHECK ADD CONSTRAINT [DF_StateLog_StateLogId] DEFAULT (NEWSEQUENTIALID()) FOR StateLogId;
|
---|
[5511] | 99 |
|
---|
| 100 | ALTER TABLE [dbo].[HiveExperimentPermission] DROP CONSTRAINT [HiveExperiment_HiveExperimentPermission]
|
---|
| 101 | ALTER TABLE [dbo].[HiveExperimentPermission] WITH CHECK ADD CONSTRAINT [HiveExperiment_HiveExperimentPermission] FOREIGN KEY([HiveExperimentId])
|
---|
| 102 | REFERENCES [dbo].[HiveExperiment] ([HiveExperimentId])
|
---|
| 103 | ON UPDATE CASCADE
|
---|
| 104 | ON DELETE CASCADE
|
---|
| 105 | GO
|
---|
| 106 |
|
---|
[6229] | 107 | ALTER TABLE [dbo].[Statistics] ALTER COLUMN StatisticsId ADD ROWGUIDCOL;
|
---|
[6419] | 108 | ALTER TABLE [dbo].[Statistics] WITH NOCHECK ADD CONSTRAINT [DF_Statistics_StatisticsId] DEFAULT (NEWSEQUENTIALID()) FOR StatisticsId;
|
---|
[6229] | 109 | GO
|
---|
| 110 |
|
---|
[6267] | 111 | ALTER TABLE [dbo].[DeletedJobStatistics] ALTER COLUMN DeletedJobStatisticsId ADD ROWGUIDCOL;
|
---|
[6419] | 112 | ALTER TABLE [dbo].[DeletedJobStatistics] WITH NOCHECK ADD CONSTRAINT [DF_DeletedJobStatistics_DeletedJobStatisticsId] DEFAULT (NEWSEQUENTIALID()) FOR DeletedJobStatisticsId;
|
---|
[6267] | 113 | GO
|
---|
| 114 |
|
---|
[6229] | 115 | ALTER TABLE [dbo].[SlaveStatistics] DROP CONSTRAINT [Statistics_SlaveStatistics]
|
---|
| 116 | ALTER TABLE [dbo].[SlaveStatistics] WITH CHECK ADD CONSTRAINT [Statistics_SlaveStatistics] FOREIGN KEY([StatisticsId])
|
---|
| 117 | REFERENCES [dbo].[Statistics] ([StatisticsId])
|
---|
| 118 | ON UPDATE CASCADE
|
---|
| 119 | ON DELETE CASCADE
|
---|
| 120 | GO
|
---|
| 121 |
|
---|
| 122 | ALTER TABLE [dbo].[UserStatistics] DROP CONSTRAINT [Statistics_UserStatistics]
|
---|
| 123 | ALTER TABLE [dbo].[UserStatistics] WITH CHECK ADD CONSTRAINT [Statistics_UserStatistics] FOREIGN KEY([StatisticsId])
|
---|
| 124 | REFERENCES [dbo].[Statistics] ([StatisticsId])
|
---|
| 125 | ON UPDATE CASCADE
|
---|
| 126 | ON DELETE CASCADE
|
---|
| 127 | GO
|
---|
| 128 |
|
---|
[4629] | 129 | /* create indices */
|
---|
[4905] | 130 | CREATE INDEX Index_RequiredPlugins_JobId ON RequiredPlugins(JobId);
|
---|
[6267] | 131 | GO
|
---|
[4905] | 132 |
|
---|
[6267] | 133 | /* views */
|
---|
| 134 | -- =============================================
|
---|
| 135 | -- Author: cneumuel
|
---|
| 136 | -- Description: Returns the first StateLog entry for each job
|
---|
| 137 | -- =============================================
|
---|
| 138 | CREATE VIEW [dbo].[view_FirstState]
|
---|
| 139 | AS
|
---|
| 140 | SELECT sl.JobId, sl.DateTime, sl.State
|
---|
| 141 | FROM dbo.StateLog AS sl INNER JOIN
|
---|
| 142 | (SELECT JobId, MIN(DateTime) AS DateTime
|
---|
| 143 | FROM dbo.StateLog
|
---|
| 144 | GROUP BY JobId) AS minDate ON sl.DateTime = minDate.DateTime AND sl.JobId = minDate.JobId
|
---|
| 145 |
|
---|
| 146 | GO
|
---|
| 147 |
|
---|
| 148 | -- =============================================
|
---|
| 149 | -- Author: cneumuel
|
---|
| 150 | -- Description: Returns the last StateLog entry for each job
|
---|
| 151 | -- =============================================
|
---|
| 152 | CREATE VIEW [dbo].[view_LastState]
|
---|
| 153 | AS
|
---|
| 154 | SELECT sl.JobId, sl.DateTime, sl.State
|
---|
| 155 | FROM dbo.StateLog AS sl INNER JOIN
|
---|
| 156 | (SELECT JobId, MAX(DateTime) AS DateTime
|
---|
| 157 | FROM dbo.StateLog
|
---|
| 158 | GROUP BY JobId) AS minDate ON sl.DateTime = minDate.DateTime AND sl.JobId = minDate.JobId
|
---|
| 159 |
|
---|
| 160 | GO
|
---|
| 161 |
|
---|
[4905] | 162 | /* triggers */
|
---|
[6033] | 163 | GO
|
---|
| 164 | /****** Object: Trigger [dbo].[tr_HiveExperimentDeleteCascade] Script Date: 04/19/2011 16:31:53 ******/
|
---|
[4905] | 165 | SET ANSI_NULLS ON
|
---|
| 166 | GO
|
---|
| 167 | SET QUOTED_IDENTIFIER ON
|
---|
| 168 | GO
|
---|
| 169 | -- =============================================
|
---|
| 170 | -- Author: cneumuel
|
---|
[6033] | 171 | -- Create date: 19.04.2011
|
---|
[6267] | 172 | -- Description: (1) Writes the execution times of deleted jobs into DeletedJobStats to ensure correct statistics
|
---|
| 173 | -- (2) Deletes all associated jobs. This cannot be done with cascading delete,
|
---|
[6006] | 174 | -- because the job table defines a INSTEAD OF DELETE trigger itself, which
|
---|
| 175 | -- is not compatible with cascading deletes.
|
---|
[4905] | 176 | -- =============================================
|
---|
[6033] | 177 | CREATE TRIGGER [dbo].[tr_HiveExperimentDeleteCascade] ON [dbo].[HiveExperiment] INSTEAD OF DELETE AS
|
---|
[6006] | 178 | BEGIN
|
---|
[6033] | 179 | DELETE Job FROM deleted, Job WHERE deleted.HiveExperimentId = Job.HiveExperimentId
|
---|
| 180 | DELETE HiveExperiment FROM deleted, HiveExperiment WHERE deleted.HiveExperimentId = HiveExperiment.HiveExperimentId
|
---|
[6006] | 181 | END
|
---|
[6033] | 182 | GO
|
---|
[4905] | 183 |
|
---|
| 184 | -- =============================================
|
---|
| 185 | -- Author: cneumuel
|
---|
| 186 | -- Create date: 11.11.2010
|
---|
| 187 | -- Description: Recursively deletes all child-jobs of a job when it is deleted. (Source: http://devio.wordpress.com/2008/05/23/recursive-delete-in-sql-server/)
|
---|
| 188 | -- =============================================
|
---|
| 189 | CREATE TRIGGER [dbo].[tr_JobDeleteCascade] ON [dbo].[Job] INSTEAD OF DELETE AS
|
---|
| 190 | BEGIN
|
---|
[6267] | 191 | -- add statistics
|
---|
| 192 | INSERT INTO dbo.DeletedJobStatistics (UserId, ExecutionTimeMs, ExecutionTimeMsFinishedJobs, StartToEndTimeMs)
|
---|
| 193 | SELECT
|
---|
| 194 | he.OwnerUserId AS UserId,
|
---|
| 195 | SUM(j.ExecutionTimeMs) AS ExecutionTimeMs,
|
---|
| 196 | SUM(CASE ls.State WHEN 'Finished' THEN j.ExecutionTimeMs END) AS ExecutionTimeMsFinishedJobs,
|
---|
| 197 | SUM(CASE ls.State WHEN 'Finished' THEN DATEDIFF(MS,fs.DateTime,ls.DateTime) ELSE 0 END) AS StartToEndMs
|
---|
| 198 | FROM
|
---|
| 199 | deleted j,
|
---|
| 200 | HiveExperiment he,
|
---|
| 201 | view_FirstState fs,
|
---|
| 202 | view_LastState ls
|
---|
| 203 | WHERE
|
---|
| 204 | he.HiveExperimentId = j.HiveExperimentId AND
|
---|
| 205 | fs.JobId = j.JobId AND
|
---|
| 206 | ls.JobId = j.JobId
|
---|
| 207 | GROUP BY he.OwnerUserId
|
---|
| 208 |
|
---|
| 209 | -- recursively delete jobs
|
---|
[4905] | 210 | CREATE TABLE #Table(
|
---|
| 211 | JobId uniqueidentifier
|
---|
| 212 | )
|
---|
| 213 | INSERT INTO #Table (JobId)
|
---|
| 214 | SELECT JobId FROM deleted
|
---|
| 215 |
|
---|
| 216 | DECLARE @c INT
|
---|
| 217 | SET @c = 0
|
---|
| 218 |
|
---|
| 219 | WHILE @c <> (SELECT COUNT(JobId) FROM #Table) BEGIN
|
---|
| 220 | SELECT @c = COUNT(JobId) FROM #Table
|
---|
| 221 |
|
---|
| 222 | INSERT INTO #Table (JobId)
|
---|
| 223 | SELECT Job.JobId
|
---|
| 224 | FROM Job
|
---|
| 225 | LEFT OUTER JOIN #Table ON Job.JobId = #Table.JobId
|
---|
| 226 | WHERE Job.ParentJobId IN (SELECT JobId FROM #Table)
|
---|
| 227 | AND #Table.JobId IS NULL
|
---|
| 228 | END
|
---|
| 229 |
|
---|
[5106] | 230 | DELETE JobData FROM JobData INNER JOIN #Table ON JobData.JobId = #Table.JobId
|
---|
[4905] | 231 | DELETE Job FROM Job INNER JOIN #Table ON Job.JobId = #Table.JobId
|
---|
| 232 | END
|
---|
[6229] | 233 | GO
|
---|
| 234 |
|
---|
| 235 | -- =============================================
|
---|
| 236 | -- Author: cneumuel
|
---|
| 237 | -- Create date: 17.05.2011
|
---|
| 238 | -- Description: Writes the execution times of deleted jobs into DeletedJobStats to ensure correct statistics
|
---|
| 239 | -- =============================================
|
---|
| 240 | --CREATE TRIGGER [dbo].[tr_DeletedJobStats] ON [dbo].[Job] AFTER DELETE AS
|
---|
| 241 | --BEGIN
|
---|
[6267] | 242 |
|
---|
| 243 |
|
---|
| 244 | --END
|
---|
| 245 | --GO
|
---|