1 | /* HeuristicLab
|
---|
2 | * Copyright (C) 2002-2016 Heuristic and Evolutionary Algorithms Laboratory (HEAL)
|
---|
3 | *
|
---|
4 | * This file is part of HeuristicLab.
|
---|
5 | *
|
---|
6 | * HeuristicLab is free software: you can redistribute it and/or modify
|
---|
7 | * it under the terms of the GNU General Public License as published by
|
---|
8 | * the Free Software Foundation, either version 3 of the License, or
|
---|
9 | * (at your option) any later version.
|
---|
10 | *
|
---|
11 | * HeuristicLab is distributed in the hope that it will be useful,
|
---|
12 | * but WITHOUT ANY WARRANTY; without even the implied warranty of
|
---|
13 | * MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the
|
---|
14 | * GNU General Public License for more details.
|
---|
15 | *
|
---|
16 | * You should have received a copy of the GNU General Public License
|
---|
17 | * along with HeuristicLab. If not, see <http://www.gnu.org/licenses/>.
|
---|
18 | */
|
---|
19 |
|
---|
20 | /* this script is supposed to be executed after the plain DB is generated by the linq-to-sql schema */
|
---|
21 | USE [HeuristicLab.Hive-3.3]
|
---|
22 |
|
---|
23 | ALTER TABLE [dbo].[AssignedProjectResource] DROP CONSTRAINT [Project_AssignedProjectResource]
|
---|
24 | ALTER TABLE [dbo].[AssignedProjectResource] WITH CHECK ADD CONSTRAINT [Project_AssignedProjectResource] FOREIGN KEY([ProjectId])
|
---|
25 | REFERENCES [dbo].[Project] ([ProjectId])
|
---|
26 | ON UPDATE CASCADE
|
---|
27 | ON DELETE CASCADE
|
---|
28 | GO
|
---|
29 | ALTER TABLE [dbo].[AssignedProjectResource] DROP CONSTRAINT [Resource_AssignedProjectResource]
|
---|
30 | ALTER TABLE [dbo].[AssignedProjectResource] WITH CHECK ADD CONSTRAINT [Resource_AssignedProjectResource] FOREIGN KEY([ResourceId])
|
---|
31 | REFERENCES [dbo].[Resource] ([ResourceId])
|
---|
32 | ON UPDATE CASCADE
|
---|
33 | ON DELETE CASCADE
|
---|
34 | GO
|
---|
35 | -- OBSOLETE (start)
|
---|
36 | ALTER TABLE [dbo].[AssignedTaskResource] DROP CONSTRAINT [Task_AssignedTaskResource]
|
---|
37 | ALTER TABLE [dbo].[AssignedTaskResource] WITH CHECK ADD CONSTRAINT [Task_AssignedTaskResource] FOREIGN KEY([TaskId])
|
---|
38 | REFERENCES [dbo].[Task] ([TaskId])
|
---|
39 | ON UPDATE CASCADE
|
---|
40 | ON DELETE CASCADE
|
---|
41 | GO
|
---|
42 | ALTER TABLE [dbo].[AssignedTaskResource] DROP CONSTRAINT [Resource_AssignedTaskResource]
|
---|
43 | ALTER TABLE [dbo].[AssignedTaskResource] WITH CHECK ADD CONSTRAINT [Resource_AssignedTaskResource] FOREIGN KEY([ResourceId])
|
---|
44 | REFERENCES [dbo].[Resource] ([ResourceId])
|
---|
45 | ON UPDATE CASCADE
|
---|
46 | ON DELETE CASCADE
|
---|
47 | GO
|
---|
48 | -- OBSOLETE (end)
|
---|
49 | ALTER TABLE [dbo].[AssignedJobResource] DROP CONSTRAINT [Job_AssignedJobResource]
|
---|
50 | ALTER TABLE [dbo].[AssignedJobResource] WITH CHECK ADD CONSTRAINT [Job_AssignedJobResource] FOREIGN KEY([JobId])
|
---|
51 | REFERENCES [dbo].[Job] ([JobId])
|
---|
52 | ON UPDATE CASCADE
|
---|
53 | ON DELETE CASCADE
|
---|
54 | GO
|
---|
55 | ALTER TABLE [dbo].[AssignedJobResource] DROP CONSTRAINT [Resource_AssignedJobResource]
|
---|
56 | ALTER TABLE [dbo].[AssignedJobResource] WITH CHECK ADD CONSTRAINT [Resource_AssignedJobResource] FOREIGN KEY([ResourceId])
|
---|
57 | REFERENCES [dbo].[Resource] ([ResourceId])
|
---|
58 | ON UPDATE CASCADE
|
---|
59 | ON DELETE CASCADE
|
---|
60 | GO
|
---|
61 |
|
---|
62 | ALTER TABLE dbo.Task ALTER COLUMN TaskId ADD ROWGUIDCOL;
|
---|
63 | ALTER TABLE dbo.Task WITH NOCHECK ADD CONSTRAINT [DF_Task_TaskId] DEFAULT (NEWSEQUENTIALID()) FOR TaskId;
|
---|
64 | GO
|
---|
65 |
|
---|
66 | ALTER TABLE [dbo].[StateLog] DROP CONSTRAINT [Task_StateLog]
|
---|
67 | ALTER TABLE [dbo].[StateLog] WITH CHECK ADD CONSTRAINT [Task_StateLog] FOREIGN KEY([TaskId])
|
---|
68 | REFERENCES [dbo].[Task] ([TaskId])
|
---|
69 | ON UPDATE CASCADE
|
---|
70 | ON DELETE CASCADE
|
---|
71 | GO
|
---|
72 | ALTER TABLE [dbo].[StateLog] DROP CONSTRAINT [Resource_StateLog]
|
---|
73 | ALTER TABLE [dbo].[StateLog] WITH CHECK ADD CONSTRAINT [Resource_StateLog] FOREIGN KEY([SlaveId])
|
---|
74 | REFERENCES [dbo].[Resource] ([ResourceId])
|
---|
75 | ON UPDATE CASCADE
|
---|
76 | ON DELETE SET NULL
|
---|
77 | GO
|
---|
78 |
|
---|
79 | ALTER TABLE dbo.Plugin ALTER COLUMN PluginId ADD ROWGUIDCOL;
|
---|
80 | ALTER TABLE dbo.Plugin WITH NOCHECK ADD CONSTRAINT [DF_Plugin_PluginId] DEFAULT (NEWSEQUENTIALID()) FOR PluginId;
|
---|
81 |
|
---|
82 | ALTER TABLE dbo.PluginData WITH NOCHECK ADD CONSTRAINT [DF_PluginData_PluginDataId] DEFAULT (NEWSEQUENTIALID()) FOR PluginDataId;
|
---|
83 |
|
---|
84 | ALTER TABLE [dbo].[PluginData] DROP CONSTRAINT [Plugin_PluginData]
|
---|
85 | ALTER TABLE [dbo].[PluginData] WITH CHECK ADD CONSTRAINT [Plugin_PluginData] FOREIGN KEY([PluginId])
|
---|
86 | REFERENCES [dbo].[Plugin] ([PluginId])
|
---|
87 | ON UPDATE CASCADE
|
---|
88 | ON DELETE CASCADE
|
---|
89 | GO
|
---|
90 |
|
---|
91 | ALTER TABLE dbo.RequiredPlugins ALTER COLUMN RequiredPluginId ADD ROWGUIDCOL;
|
---|
92 | ALTER TABLE dbo.RequiredPlugins WITH NOCHECK ADD CONSTRAINT [DF_RequiredPlugins_RequiredPluginId] DEFAULT (NEWSEQUENTIALID()) FOR RequiredPluginId;
|
---|
93 |
|
---|
94 | ALTER TABLE [dbo].[RequiredPlugins] DROP CONSTRAINT [Task_RequiredPlugin]
|
---|
95 | ALTER TABLE [dbo].[RequiredPlugins] WITH CHECK ADD CONSTRAINT [Task_RequiredPlugin] FOREIGN KEY([TaskId])
|
---|
96 | REFERENCES [dbo].[Task] ([TaskId])
|
---|
97 | ON UPDATE CASCADE
|
---|
98 | ON DELETE CASCADE
|
---|
99 | GO
|
---|
100 |
|
---|
101 | ALTER TABLE [dbo].[RequiredPlugins] DROP CONSTRAINT [Plugin_RequiredPlugin]
|
---|
102 | ALTER TABLE [dbo].[RequiredPlugins] WITH CHECK ADD CONSTRAINT [Plugin_RequiredPlugin] FOREIGN KEY([PluginId])
|
---|
103 | REFERENCES [dbo].[Plugin] ([PluginId])
|
---|
104 | ON UPDATE CASCADE
|
---|
105 | ON DELETE CASCADE
|
---|
106 | GO
|
---|
107 |
|
---|
108 | ALTER TABLE dbo.Resource ALTER COLUMN ResourceId ADD ROWGUIDCOL;
|
---|
109 | ALTER TABLE dbo.Resource WITH NOCHECK ADD CONSTRAINT [DF_Resource_ResourceId] DEFAULT (NEWSEQUENTIALID()) FOR ResourceId;
|
---|
110 |
|
---|
111 | ALTER TABLE dbo.Downtime ALTER COLUMN DowntimeId ADD ROWGUIDCOL;
|
---|
112 | ALTER TABLE dbo.Downtime WITH NOCHECK ADD CONSTRAINT [DF_Downtime_DowntimeId] DEFAULT (NEWSEQUENTIALID()) FOR DowntimeId;
|
---|
113 |
|
---|
114 | ALTER TABLE dbo.Job ALTER COLUMN JobId ADD ROWGUIDCOL;
|
---|
115 | ALTER TABLE dbo.Job WITH NOCHECK ADD CONSTRAINT [DF_Job_JobId] DEFAULT (NEWSEQUENTIALID()) FOR JobId;
|
---|
116 | ALTER TABLE [dbo].[Job] DROP CONSTRAINT [Project_Job]
|
---|
117 | ALTER TABLE [dbo].[Job] WITH CHECK ADD CONSTRAINT [Project_Job] FOREIGN KEY([ProjectId])
|
---|
118 | REFERENCES [dbo].[Project] ([ProjectId])
|
---|
119 | ON UPDATE CASCADE
|
---|
120 | -- ON DELETE CASCADE (no "ON DELETE CASCADE" >>> if project is deleted, jobs (actually job-belonging tasks) should be aborted, but not deleted
|
---|
121 | GO
|
---|
122 |
|
---|
123 | ALTER TABLE dbo.StateLog ALTER COLUMN StateLogId ADD ROWGUIDCOL;
|
---|
124 | ALTER TABLE dbo.StateLog WITH NOCHECK ADD CONSTRAINT [DF_StateLog_StateLogId] DEFAULT (NEWSEQUENTIALID()) FOR StateLogId;
|
---|
125 |
|
---|
126 | ALTER TABLE [dbo].[JobPermission] DROP CONSTRAINT [Job_JobPermission]
|
---|
127 | ALTER TABLE [dbo].[JobPermission] WITH CHECK ADD CONSTRAINT [Job_JobPermission] FOREIGN KEY([JobId])
|
---|
128 | REFERENCES [dbo].[Job] ([JobId])
|
---|
129 | ON UPDATE CASCADE
|
---|
130 | ON DELETE CASCADE
|
---|
131 | GO
|
---|
132 |
|
---|
133 | ALTER TABLE dbo.Project ALTER COLUMN ProjectId ADD ROWGUIDCOL;
|
---|
134 | ALTER TABLE dbo.Project WITH NOCHECK ADD CONSTRAINT [DF_Project_ProjectId] DEFAULT (NEWSEQUENTIALID()) FOR ProjectId;
|
---|
135 |
|
---|
136 | ALTER TABLE [dbo].[ProjectPermission] DROP CONSTRAINT [Project_ProjectPermission]
|
---|
137 | ALTER TABLE [dbo].[ProjectPermission] WITH CHECK ADD CONSTRAINT [Project_ProjectPermission] FOREIGN KEY([ProjectId])
|
---|
138 | REFERENCES [dbo].[Project] ([ProjectId])
|
---|
139 | ON UPDATE CASCADE
|
---|
140 | ON DELETE CASCADE
|
---|
141 | GO
|
---|
142 |
|
---|
143 | /* create indices */
|
---|
144 | CREATE INDEX Index_RequiredPlugins_TaskId ON RequiredPlugins(TaskId);
|
---|
145 | GO
|
---|
146 |
|
---|
147 | -- speed up joins between Job and Task
|
---|
148 | CREATE NONCLUSTERED INDEX [TaskJobIdIndex]
|
---|
149 | ON [dbo].[Task] ([JobId])
|
---|
150 | INCLUDE ([TaskId],[TaskState],[ExecutionTimeMs],[LastHeartbeat],[ParentTaskId],[Priority],[CoresNeeded],[MemoryNeeded],[IsParentTask],[FinishWhenChildJobsFinished],[Command])
|
---|
151 | GO
|
---|
152 |
|
---|
153 | -- this is an index to speed up the GetWaitingTasks() method
|
---|
154 | CREATE NONCLUSTERED INDEX [TaskGetWaitingTasksIndex]
|
---|
155 | ON [dbo].[Task] ([TaskState],[IsParentTask],[FinishWhenChildJobsFinished],[CoresNeeded],[MemoryNeeded])
|
---|
156 | INCLUDE ([TaskId],[ExecutionTimeMs],[LastHeartbeat],[ParentTaskId],[Priority],[Command],[JobId])
|
---|
157 | GO
|
---|
158 |
|
---|
159 |
|
---|
160 |
|
---|
161 | -- OBSOLETE (start)
|
---|
162 | /****** Object: Trigger [dbo].[tr_JobDeleteCascade] Script Date: 04/19/2011 16:31:53 ******/
|
---|
163 | SET ANSI_NULLS ON
|
---|
164 | GO
|
---|
165 | SET QUOTED_IDENTIFIER ON
|
---|
166 | GO
|
---|
167 | -- =============================================
|
---|
168 | -- Author: cneumuel
|
---|
169 | -- Create date: 19.04.2011
|
---|
170 | -- Description: (1) Writes the execution times of deleted jobs into DeletedJobStats to ensure correct statistics
|
---|
171 | -- (2) Deletes all associated jobs. This cannot be done with cascading delete,
|
---|
172 | -- because the job table defines a INSTEAD OF DELETE trigger itself, which
|
---|
173 | -- is not compatible with cascading deletes.
|
---|
174 | -- =============================================
|
---|
175 | CREATE TRIGGER [dbo].[tr_JobDeleteCascade] ON [dbo].[Job] INSTEAD OF DELETE AS
|
---|
176 | BEGIN
|
---|
177 | DELETE Task FROM deleted, Task WHERE deleted.JobId = Task.JobId
|
---|
178 | DELETE Job FROM deleted, Job WHERE deleted.JobId = Job.JobId
|
---|
179 | END
|
---|
180 | GO
|
---|
181 |
|
---|
182 | -- =============================================
|
---|
183 | -- Author: cneumuel
|
---|
184 | -- Create date: 11.11.2010
|
---|
185 | -- 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/)
|
---|
186 | -- =============================================DeletedJobStatistics
|
---|
187 | CREATE TRIGGER [dbo].[tr_TaskDeleteCascade] ON [dbo].[Task] INSTEAD OF DELETE AS
|
---|
188 | BEGIN
|
---|
189 | -- recursively delete jobs
|
---|
190 | CREATE TABLE #Table(
|
---|
191 | TaskId uniqueidentifier
|
---|
192 | )
|
---|
193 | INSERT INTO #Table (TaskId)
|
---|
194 | SELECT TaskId FROM deleted
|
---|
195 |
|
---|
196 | DECLARE @c INT
|
---|
197 | SET @c = 0
|
---|
198 |
|
---|
199 | WHILE @c <> (SELECT COUNT(TaskId) FROM #Table) BEGIN
|
---|
200 | SELECT @c = COUNT(TaskId) FROM #Table
|
---|
201 |
|
---|
202 | INSERT INTO #Table (TaskId)
|
---|
203 | SELECT Task.TaskId
|
---|
204 | FROM Task
|
---|
205 | LEFT OUTER JOIN #Table ON Task.TaskId = #Table.TaskId
|
---|
206 | WHERE Task.ParentTaskId IN (SELECT TaskId FROM #Table)
|
---|
207 | AND #Table.TaskId IS NULL
|
---|
208 | END
|
---|
209 |
|
---|
210 | DELETE TaskData FROM TaskData INNER JOIN #Table ON TaskData.TaskId = #Table.TaskId
|
---|
211 | DELETE Task FROM Task INNER JOIN #Table ON Task.TaskId = #Table.TaskId
|
---|
212 | END
|
---|
213 | GO
|
---|
214 | -- OBSOLETE (end)
|
---|
215 |
|
---|