Free cookie consent management tool by TermsFeed Policy Generator

source: branches/HiveProjectManagement/HeuristicLab.Services.Hive.DataAccess/3.3/SQL Scripts/Prepare Hive Database.sql @ 15528

Last change on this file since 15528 was 15528, checked in by jzenisek, 6 years ago

#2839 added AssignedJobResource to dbml and Daos

File size: 8.5 KB
Line 
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 */
21USE [HeuristicLab.Hive-3.3]
22
23ALTER TABLE [dbo].[AssignedProjectResource]  DROP  CONSTRAINT [Project_AssignedProjectResource]
24ALTER TABLE [dbo].[AssignedProjectResource]  WITH CHECK ADD  CONSTRAINT [Project_AssignedProjectResource] FOREIGN KEY([ProjectId])
25REFERENCES [dbo].[Project] ([ProjectId])
26ON UPDATE CASCADE
27ON DELETE CASCADE
28GO
29ALTER TABLE [dbo].[AssignedProjectResource]  DROP  CONSTRAINT [Resource_AssignedProjectResource]
30ALTER TABLE [dbo].[AssignedProjectResource]  WITH CHECK ADD  CONSTRAINT [Resource_AssignedProjectResource] FOREIGN KEY([ResourceId])
31REFERENCES [dbo].[Resource] ([ResourceId])
32ON UPDATE CASCADE
33ON DELETE CASCADE
34GO
35
36ALTER TABLE [dbo].[AssignedTaskResource]  DROP  CONSTRAINT [Task_AssignedTaskResource]
37ALTER TABLE [dbo].[AssignedTaskResource]  WITH CHECK ADD  CONSTRAINT [Task_AssignedTaskResource] FOREIGN KEY([TaskId])
38REFERENCES [dbo].[Task] ([TaskId])
39ON UPDATE CASCADE
40ON DELETE CASCADE
41GO
42ALTER TABLE [dbo].[AssignedTaskResource]  DROP  CONSTRAINT [Resource_AssignedTaskResource]
43ALTER TABLE [dbo].[AssignedTaskResource]  WITH CHECK ADD  CONSTRAINT [Resource_AssignedTaskResource] FOREIGN KEY([ResourceId])
44REFERENCES [dbo].[Resource] ([ResourceId])
45ON UPDATE CASCADE
46ON DELETE CASCADE
47GO
48
49ALTER TABLE dbo.Task ALTER COLUMN TaskId ADD ROWGUIDCOL;
50ALTER TABLE dbo.Task WITH NOCHECK ADD CONSTRAINT [DF_Task_TaskId] DEFAULT (NEWSEQUENTIALID()) FOR TaskId;
51GO
52
53ALTER TABLE [dbo].[StateLog]  DROP  CONSTRAINT [Task_StateLog]
54ALTER TABLE [dbo].[StateLog]  WITH CHECK ADD CONSTRAINT [Task_StateLog] FOREIGN KEY([TaskId])
55REFERENCES [dbo].[Task] ([TaskId])
56ON UPDATE CASCADE
57ON DELETE CASCADE
58GO
59ALTER TABLE [dbo].[StateLog]  DROP  CONSTRAINT [Resource_StateLog]
60ALTER TABLE [dbo].[StateLog]  WITH CHECK ADD CONSTRAINT [Resource_StateLog] FOREIGN KEY([SlaveId])
61REFERENCES [dbo].[Resource] ([ResourceId])
62ON UPDATE CASCADE
63ON DELETE SET NULL
64GO
65
66ALTER TABLE dbo.Plugin ALTER COLUMN PluginId ADD ROWGUIDCOL;
67ALTER TABLE dbo.Plugin WITH NOCHECK ADD CONSTRAINT [DF_Plugin_PluginId] DEFAULT (NEWSEQUENTIALID()) FOR PluginId;
68
69ALTER TABLE dbo.PluginData WITH NOCHECK ADD CONSTRAINT [DF_PluginData_PluginDataId] DEFAULT (NEWSEQUENTIALID()) FOR PluginDataId;
70
71ALTER TABLE [dbo].[PluginData]  DROP  CONSTRAINT [Plugin_PluginData]
72ALTER TABLE [dbo].[PluginData]  WITH CHECK ADD  CONSTRAINT [Plugin_PluginData] FOREIGN KEY([PluginId])
73REFERENCES [dbo].[Plugin] ([PluginId])
74ON UPDATE CASCADE
75ON DELETE CASCADE
76GO
77
78ALTER TABLE dbo.RequiredPlugins ALTER COLUMN RequiredPluginId ADD ROWGUIDCOL;
79ALTER TABLE dbo.RequiredPlugins WITH NOCHECK ADD CONSTRAINT [DF_RequiredPlugins_RequiredPluginId] DEFAULT (NEWSEQUENTIALID()) FOR RequiredPluginId;
80
81ALTER TABLE [dbo].[RequiredPlugins]  DROP  CONSTRAINT [Task_RequiredPlugin]
82ALTER TABLE [dbo].[RequiredPlugins]  WITH CHECK ADD  CONSTRAINT [Task_RequiredPlugin] FOREIGN KEY([TaskId])
83REFERENCES [dbo].[Task] ([TaskId])
84ON UPDATE CASCADE
85ON DELETE CASCADE
86GO
87
88ALTER TABLE [dbo].[RequiredPlugins]  DROP  CONSTRAINT [Plugin_RequiredPlugin]
89ALTER TABLE [dbo].[RequiredPlugins]  WITH CHECK ADD  CONSTRAINT [Plugin_RequiredPlugin] FOREIGN KEY([PluginId])
90REFERENCES [dbo].[Plugin] ([PluginId])
91ON UPDATE CASCADE
92ON DELETE CASCADE
93GO
94
95ALTER TABLE dbo.Resource ALTER COLUMN ResourceId ADD ROWGUIDCOL;
96ALTER TABLE dbo.Resource WITH NOCHECK ADD CONSTRAINT [DF_Resource_ResourceId] DEFAULT (NEWSEQUENTIALID()) FOR ResourceId;
97
98ALTER TABLE dbo.Downtime ALTER COLUMN DowntimeId ADD ROWGUIDCOL;
99ALTER TABLE dbo.Downtime WITH NOCHECK ADD CONSTRAINT [DF_Downtime_DowntimeId] DEFAULT (NEWSEQUENTIALID()) FOR DowntimeId;
100
101ALTER TABLE dbo.Job ALTER COLUMN JobId ADD ROWGUIDCOL;
102ALTER TABLE dbo.Job WITH NOCHECK ADD CONSTRAINT [DF_Job_JobId] DEFAULT (NEWSEQUENTIALID()) FOR JobId;
103ALTER TABLE [dbo].[Job]  DROP  CONSTRAINT [Project_Job]
104ALTER TABLE [dbo].[Job]  WITH CHECK ADD  CONSTRAINT [Project_Job] FOREIGN KEY([ProjectId])
105REFERENCES [dbo].[Project] ([ProjectId])
106ON UPDATE CASCADE
107ON DELETE CASCADE
108GO
109
110ALTER TABLE dbo.StateLog ALTER COLUMN StateLogId ADD ROWGUIDCOL;
111ALTER TABLE dbo.StateLog WITH NOCHECK ADD CONSTRAINT [DF_StateLog_StateLogId] DEFAULT (NEWSEQUENTIALID()) FOR StateLogId;
112
113ALTER TABLE [dbo].[JobPermission]  DROP  CONSTRAINT [Job_JobPermission]
114ALTER TABLE [dbo].[JobPermission]  WITH CHECK ADD CONSTRAINT [Job_JobPermission] FOREIGN KEY([JobId])
115REFERENCES [dbo].[Job] ([JobId])
116ON UPDATE CASCADE
117ON DELETE CASCADE
118GO
119
120ALTER TABLE dbo.Project ALTER COLUMN ProjectId ADD ROWGUIDCOL;
121ALTER TABLE dbo.Project WITH NOCHECK ADD CONSTRAINT [DF_Project_ProjectId] DEFAULT (NEWSEQUENTIALID()) FOR ProjectId;
122
123ALTER TABLE [dbo].[ProjectPermission]  DROP  CONSTRAINT [Project_ProjectPermission]
124ALTER TABLE [dbo].[ProjectPermission]  WITH CHECK ADD CONSTRAINT [Project_ProjectPermission] FOREIGN KEY([ProjectId])
125REFERENCES [dbo].[Project] ([ProjectId])
126ON UPDATE CASCADE
127ON DELETE CASCADE
128GO
129
130/* create indices */
131CREATE INDEX Index_RequiredPlugins_TaskId ON RequiredPlugins(TaskId);
132GO
133
134-- speed up joins between Job and Task
135CREATE NONCLUSTERED INDEX [TaskJobIdIndex]
136ON [dbo].[Task] ([JobId])
137INCLUDE ([TaskId],[TaskState],[ExecutionTimeMs],[LastHeartbeat],[ParentTaskId],[Priority],[CoresNeeded],[MemoryNeeded],[IsParentTask],[FinishWhenChildJobsFinished],[Command])
138GO
139
140-- this is an index to speed up the GetWaitingTasks() method
141CREATE NONCLUSTERED INDEX [TaskGetWaitingTasksIndex]
142ON [dbo].[Task] ([TaskState],[IsParentTask],[FinishWhenChildJobsFinished],[CoresNeeded],[MemoryNeeded])
143INCLUDE ([TaskId],[ExecutionTimeMs],[LastHeartbeat],[ParentTaskId],[Priority],[Command],[JobId])
144GO
145
146
147/****** Object:  Trigger [dbo].[tr_JobDeleteCascade]    Script Date: 04/19/2011 16:31:53 ******/
148SET ANSI_NULLS ON
149GO
150SET QUOTED_IDENTIFIER ON
151GO
152-- =============================================
153-- Author:    cneumuel
154-- Create date: 19.04.2011
155-- Description: (1) Writes the execution times of deleted jobs into DeletedJobStats to ensure correct statistics
156--        (2) Deletes all associated jobs. This cannot be done with cascading delete,
157--              because the job table defines a INSTEAD OF DELETE trigger itself, which
158--              is not compatible with cascading deletes.
159-- =============================================
160CREATE TRIGGER [dbo].[tr_JobDeleteCascade] ON [dbo].[Job] INSTEAD OF DELETE AS
161BEGIN
162    DELETE Task FROM deleted, Task WHERE deleted.JobId = Task.JobId
163    DELETE Job FROM deleted, Job WHERE deleted.JobId = Job.JobId
164END
165GO
166
167-- =============================================
168-- Author:    cneumuel
169-- Create date: 11.11.2010
170-- 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/)
171-- =============================================DeletedJobStatistics
172CREATE TRIGGER [dbo].[tr_TaskDeleteCascade] ON [dbo].[Task] INSTEAD OF DELETE AS
173BEGIN
174    -- recursively delete jobs
175    CREATE TABLE #Table(
176        TaskId uniqueidentifier
177    )
178    INSERT INTO #Table (TaskId)
179    SELECT TaskId FROM deleted
180   
181    DECLARE @c INT
182    SET @c = 0
183   
184    WHILE @c <> (SELECT COUNT(TaskId) FROM #Table) BEGIN
185        SELECT @c = COUNT(TaskId) FROM #Table
186       
187        INSERT INTO #Table (TaskId)
188            SELECT Task.TaskId
189            FROM Task
190            LEFT OUTER JOIN #Table ON Task.TaskId = #Table.TaskId
191            WHERE Task.ParentTaskId IN (SELECT TaskId FROM #Table)
192                AND #Table.TaskId IS NULL
193    END
194   
195    DELETE TaskData FROM TaskData INNER JOIN #Table ON TaskData.TaskId = #Table.TaskId
196    DELETE Task FROM Task INNER JOIN #Table ON Task.TaskId = #Table.TaskId
197END
198GO
199
200
Note: See TracBrowser for help on using the repository browser.