Free cookie consent management tool by TermsFeed Policy Generator

source: branches/HeuristicLab.Hive-3.4/sources/HeuristicLab.Services.Hive.DataAccess/3.4/Tools/prepareHiveDatabase.sql @ 6419

Last change on this file since 6419 was 6419, checked in by cneumuel, 13 years ago

#1233

  • created events when statelog changed
  • fixed memory leak in hiveengine
  • extended timeout for long running transactions and database contexts (when jobdata is stored)
  • replaced random guids in database with sequential guids for performance reasons
  • minor fixes and cleanups
File size: 10.7 KB
Line 
1USE [HeuristicLab.Hive-3.4]
2/* this script is supposed to be executed after the plain DB is generated by the linq-to-sql schema */
3
4/* use these DROP commands if you want to run this query a second time on the same db */
5
6/*
7ALTER TABLE dbo.AssignedResources ALTER COLUMN AssignedRessourcesId DROP ROWGUIDCOL;
8ALTER TABLE dbo.Job ALTER COLUMN JobId DROP ROWGUIDCOL;
9ALTER TABLE dbo.SlaveGroup_Resource ALTER COLUMN SlaveGroup_RessourceId DROP ROWGUIDCOL;
10ALTER TABLE dbo.Plugin ALTER COLUMN PluginId DROP ROWGUIDCOL;
11ALTER TABLE dbo.RequiredPlugins ALTER COLUMN RequiredPluginId DROP ROWGUIDCOL;
12ALTER TABLE dbo.Resource ALTER COLUMN ResourceId DROP ROWGUIDCOL;
13ALTER TABLE dbo.UptimeCalendar ALTER COLUMN UptimeCalendarId DROP ROWGUIDCOL;
14ALTER TABLE dbo.HiveExperiment ALTER COLUMN HiveExperimentId DROP ROWGUIDCOL;
15
16ALTER TABLE dbo.AssignedResources DROP CONSTRAINT [DF_AssignedResources_AssignedRessourcesId];
17ALTER TABLE dbo.Job DROP CONSTRAINT [DF_Job_JobId];
18ALTER TABLE dbo.SlaveGroup_Resource DROP CONSTRAINT [DF_SlaveGroup_ResourceSlaveGroup_RessourceId];
19ALTER TABLE dbo.Plugin DROP CONSTRAINT [DF_Plugin_PluginId];
20ALTER TABLE dbo.RequiredPlugins DROP CONSTRAINT [DF_RequiredPlugins_RequiredPluginId];
21ALTER TABLE dbo.Resource DROP CONSTRAINT [DF_Resource_ResourceId];
22ALTER TABLE dbo.UptimeCalendar DROP CONSTRAINT [DF_UptimeCalendar_UptimeCalendarId];
23ALTER TABLE dbo.HiveExperiment DROP CONSTRAINT [DF_HiveExperiment_HiveExperimentId];
24*/
25
26ALTER TABLE dbo.AssignedResources ALTER COLUMN AssignedRessourcesId ADD ROWGUIDCOL;
27ALTER TABLE dbo.AssignedResources WITH NOCHECK ADD CONSTRAINT [DF_AssignedResources_AssignedRessourcesId] DEFAULT (NEWSEQUENTIALID()) FOR AssignedRessourcesId;
28ALTER TABLE [dbo].[AssignedResources]  DROP  CONSTRAINT [Job_AssignedResource]
29ALTER TABLE [dbo].[AssignedResources]  WITH CHECK ADD  CONSTRAINT [Job_AssignedResource] FOREIGN KEY([JobId])
30REFERENCES [dbo].[Job] ([JobId])
31ON UPDATE CASCADE
32ON DELETE CASCADE
33GO
34ALTER TABLE [dbo].[AssignedResources]  DROP  CONSTRAINT [Resource_AssignedResource]
35ALTER TABLE [dbo].[AssignedResources]  WITH CHECK ADD  CONSTRAINT [Resource_AssignedResource] FOREIGN KEY([ResourceId])
36REFERENCES [dbo].[Resource] ([ResourceId])
37ON UPDATE CASCADE
38ON DELETE CASCADE
39GO
40
41ALTER TABLE dbo.Job ALTER COLUMN JobId ADD ROWGUIDCOL;
42ALTER TABLE dbo.Job WITH NOCHECK ADD CONSTRAINT [DF_Job_JobId] DEFAULT (NEWSEQUENTIALID()) FOR JobId;
43GO
44
45ALTER TABLE [dbo].[StateLog]  DROP  CONSTRAINT [Job_StateLog]
46ALTER TABLE [dbo].[StateLog]  WITH CHECK ADD CONSTRAINT [Job_StateLog] FOREIGN KEY([JobId])
47REFERENCES [dbo].[Job] ([JobId])
48ON UPDATE CASCADE
49ON DELETE CASCADE
50GO
51ALTER TABLE [dbo].[StateLog]  DROP  CONSTRAINT [Resource_StateLog]
52ALTER TABLE [dbo].[StateLog]  WITH CHECK ADD CONSTRAINT [Resource_StateLog] FOREIGN KEY([SlaveId])
53REFERENCES [dbo].[Resource] ([ResourceId])
54ON UPDATE CASCADE
55ON DELETE SET NULL
56GO
57
58ALTER TABLE dbo.Plugin ALTER COLUMN PluginId ADD ROWGUIDCOL;
59ALTER TABLE dbo.Plugin WITH NOCHECK ADD CONSTRAINT [DF_Plugin_PluginId] DEFAULT (NEWSEQUENTIALID()) FOR PluginId;
60
61ALTER TABLE dbo.PluginData ALTER COLUMN PluginDataId ADD ROWGUIDCOL;
62ALTER TABLE dbo.PluginData WITH NOCHECK ADD CONSTRAINT [DF_PluginData_PluginDataId] DEFAULT (NEWSEQUENTIALID()) FOR PluginDataId;
63
64ALTER TABLE [dbo].[PluginData]  DROP  CONSTRAINT [Plugin_PluginData]
65ALTER TABLE [dbo].[PluginData]  WITH CHECK ADD  CONSTRAINT [Plugin_PluginData] FOREIGN KEY([PluginId])
66REFERENCES [dbo].[Plugin] ([PluginId])
67ON UPDATE CASCADE
68ON DELETE CASCADE
69GO
70
71ALTER TABLE dbo.RequiredPlugins ALTER COLUMN RequiredPluginId ADD ROWGUIDCOL;
72ALTER TABLE dbo.RequiredPlugins WITH NOCHECK ADD CONSTRAINT [DF_RequiredPlugins_RequiredPluginId] DEFAULT (NEWSEQUENTIALID()) FOR RequiredPluginId;
73
74ALTER TABLE [dbo].[RequiredPlugins]  DROP  CONSTRAINT [Job_RequiredPlugin]
75ALTER TABLE [dbo].[RequiredPlugins]  WITH CHECK ADD  CONSTRAINT [Job_RequiredPlugin] FOREIGN KEY([JobId])
76REFERENCES [dbo].[Job] ([JobId])
77ON UPDATE CASCADE
78ON DELETE CASCADE
79GO
80
81ALTER TABLE [dbo].[RequiredPlugins]  DROP  CONSTRAINT [Plugin_RequiredPlugin]
82ALTER TABLE [dbo].[RequiredPlugins]  WITH CHECK ADD  CONSTRAINT [Plugin_RequiredPlugin] FOREIGN KEY([PluginId])
83REFERENCES [dbo].[Plugin] ([PluginId])
84ON UPDATE CASCADE
85ON DELETE CASCADE
86GO
87
88ALTER TABLE dbo.Resource ALTER COLUMN ResourceId ADD ROWGUIDCOL;
89ALTER TABLE dbo.Resource WITH NOCHECK ADD CONSTRAINT [DF_Resource_ResourceId] DEFAULT (NEWSEQUENTIALID()) FOR ResourceId;
90
91ALTER TABLE dbo.UptimeCalendar ALTER COLUMN UptimeCalendarId ADD ROWGUIDCOL;
92ALTER TABLE dbo.UptimeCalendar WITH NOCHECK ADD CONSTRAINT [DF_UptimeCalendar_UptimeCalendarId] DEFAULT (NEWSEQUENTIALID()) FOR UptimeCalendarId;
93
94ALTER TABLE dbo.HiveExperiment ALTER COLUMN HiveExperimentId ADD ROWGUIDCOL;
95ALTER TABLE dbo.HiveExperiment WITH NOCHECK ADD CONSTRAINT [DF_HiveExperiment_HiveExperimentId] DEFAULT (NEWSEQUENTIALID()) FOR HiveExperimentId;
96
97ALTER TABLE dbo.StateLog ALTER COLUMN StateLogId ADD ROWGUIDCOL;
98ALTER TABLE dbo.StateLog WITH NOCHECK ADD CONSTRAINT [DF_StateLog_StateLogId] DEFAULT (NEWSEQUENTIALID()) FOR StateLogId;
99
100ALTER TABLE [dbo].[HiveExperimentPermission]  DROP  CONSTRAINT [HiveExperiment_HiveExperimentPermission]
101ALTER TABLE [dbo].[HiveExperimentPermission]  WITH CHECK ADD CONSTRAINT [HiveExperiment_HiveExperimentPermission] FOREIGN KEY([HiveExperimentId])
102REFERENCES [dbo].[HiveExperiment] ([HiveExperimentId])
103ON UPDATE CASCADE
104ON DELETE CASCADE
105GO
106
107ALTER TABLE [dbo].[Statistics] ALTER COLUMN StatisticsId ADD ROWGUIDCOL;
108ALTER TABLE [dbo].[Statistics] WITH NOCHECK ADD CONSTRAINT [DF_Statistics_StatisticsId] DEFAULT (NEWSEQUENTIALID()) FOR StatisticsId;
109GO
110
111ALTER TABLE [dbo].[DeletedJobStatistics] ALTER COLUMN DeletedJobStatisticsId ADD ROWGUIDCOL;
112ALTER TABLE [dbo].[DeletedJobStatistics] WITH NOCHECK ADD CONSTRAINT [DF_DeletedJobStatistics_DeletedJobStatisticsId] DEFAULT (NEWSEQUENTIALID()) FOR DeletedJobStatisticsId;
113GO
114
115ALTER TABLE [dbo].[SlaveStatistics]  DROP  CONSTRAINT [Statistics_SlaveStatistics]
116ALTER TABLE [dbo].[SlaveStatistics]  WITH CHECK ADD  CONSTRAINT [Statistics_SlaveStatistics] FOREIGN KEY([StatisticsId])
117REFERENCES [dbo].[Statistics] ([StatisticsId])
118ON UPDATE CASCADE
119ON DELETE CASCADE
120GO
121
122ALTER TABLE [dbo].[UserStatistics]  DROP  CONSTRAINT [Statistics_UserStatistics]
123ALTER TABLE [dbo].[UserStatistics]  WITH CHECK ADD  CONSTRAINT [Statistics_UserStatistics] FOREIGN KEY([StatisticsId])
124REFERENCES [dbo].[Statistics] ([StatisticsId])
125ON UPDATE CASCADE
126ON DELETE CASCADE
127GO
128
129/* create indices */
130CREATE INDEX Index_RequiredPlugins_JobId ON RequiredPlugins(JobId);
131GO
132
133/* views */
134-- =============================================
135-- Author:    cneumuel
136-- Description: Returns the first StateLog entry for each job
137-- =============================================
138CREATE VIEW [dbo].[view_FirstState]
139AS
140SELECT     sl.JobId, sl.DateTime, sl.State
141FROM         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
146GO
147
148-- =============================================
149-- Author:    cneumuel
150-- Description: Returns the last StateLog entry for each job
151-- =============================================
152CREATE VIEW [dbo].[view_LastState]
153AS
154SELECT     sl.JobId, sl.DateTime, sl.State
155FROM         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
160GO
161
162/* triggers */
163GO
164/****** Object:  Trigger [dbo].[tr_HiveExperimentDeleteCascade]    Script Date: 04/19/2011 16:31:53 ******/
165SET ANSI_NULLS ON
166GO
167SET QUOTED_IDENTIFIER ON
168GO
169-- =============================================
170-- Author:    cneumuel
171-- Create date: 19.04.2011
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,
174--              because the job table defines a INSTEAD OF DELETE trigger itself, which
175--              is not compatible with cascading deletes.
176-- =============================================
177CREATE TRIGGER [dbo].[tr_HiveExperimentDeleteCascade] ON [dbo].[HiveExperiment] INSTEAD OF DELETE AS
178BEGIN
179  DELETE Job FROM deleted, Job WHERE deleted.HiveExperimentId = Job.HiveExperimentId
180  DELETE HiveExperiment FROM deleted, HiveExperiment WHERE deleted.HiveExperimentId = HiveExperiment.HiveExperimentId
181END
182GO
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-- =============================================
189CREATE TRIGGER [dbo].[tr_JobDeleteCascade] ON [dbo].[Job] INSTEAD OF DELETE AS
190BEGIN
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
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 
230  DELETE JobData FROM JobData INNER JOIN #Table ON JobData.JobId = #Table.JobId
231  DELETE Job FROM Job INNER JOIN #Table ON Job.JobId = #Table.JobId
232END
233GO
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
242
243
244--END
245--GO
Note: See TracBrowser for help on using the repository browser.