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 @ 5593

Last change on this file since 5593 was 5511, checked in by cneumuel, 14 years ago

#1233

  • added StateLog to log state transitions of hive jobs
  • added permissions to hive experiments (in data access layer, no UI for that yet)
  • extended unit tests
File size: 6.4 KB
Line 
1/* this script is supposed to be executed after the plain DB is generated by the linq-to-sql schema */
2
3/* use these DROP commands if you want to run this query a second time on the same db */
4
5/*
6ALTER TABLE dbo.AssignedResources ALTER COLUMN AssignedRessourcesId DROP ROWGUIDCOL;
7ALTER TABLE dbo.Job ALTER COLUMN JobId DROP ROWGUIDCOL;
8ALTER TABLE dbo.SlaveGroup_Resource ALTER COLUMN SlaveGroup_RessourceId DROP ROWGUIDCOL;
9ALTER TABLE dbo.Plugin ALTER COLUMN PluginId DROP ROWGUIDCOL;
10ALTER TABLE dbo.RequiredPlugins ALTER COLUMN RequiredPluginId DROP ROWGUIDCOL;
11ALTER TABLE dbo.Resource ALTER COLUMN ResourceId DROP ROWGUIDCOL;
12ALTER TABLE dbo.UptimeCalendar ALTER COLUMN UptimeCalendarId DROP ROWGUIDCOL;
13ALTER TABLE dbo.HiveExperiment ALTER COLUMN HiveExperimentId DROP ROWGUIDCOL;
14
15ALTER TABLE dbo.AssignedResources DROP CONSTRAINT [DF_AssignedResources_AssignedRessourcesId];
16ALTER TABLE dbo.Job DROP CONSTRAINT [DF_Job_JobId];
17ALTER TABLE dbo.SlaveGroup_Resource DROP CONSTRAINT [DF_SlaveGroup_ResourceSlaveGroup_RessourceId];
18ALTER TABLE dbo.Plugin DROP CONSTRAINT [DF_Plugin_PluginId];
19ALTER TABLE dbo.RequiredPlugins DROP CONSTRAINT [DF_RequiredPlugins_RequiredPluginId];
20ALTER TABLE dbo.Resource DROP CONSTRAINT [DF_Resource_ResourceId];
21ALTER TABLE dbo.UptimeCalendar DROP CONSTRAINT [DF_UptimeCalendar_UptimeCalendarId];
22ALTER TABLE dbo.HiveExperiment DROP CONSTRAINT [DF_HiveExperiment_HiveExperimentId];
23*/
24
25ALTER TABLE dbo.AssignedResources ALTER COLUMN AssignedRessourcesId ADD ROWGUIDCOL;
26ALTER TABLE dbo.AssignedResources WITH NOCHECK ADD CONSTRAINT [DF_AssignedResources_AssignedRessourcesId] DEFAULT (newid()) FOR AssignedRessourcesId;
27ALTER TABLE [dbo].[AssignedResources]  DROP  CONSTRAINT [Job_AssignedResource]
28ALTER TABLE [dbo].[AssignedResources]  WITH CHECK ADD  CONSTRAINT [Job_AssignedResource] FOREIGN KEY([JobId])
29REFERENCES [dbo].[Job] ([JobId])
30ON UPDATE CASCADE
31ON DELETE CASCADE
32GO
33ALTER TABLE [dbo].[AssignedResources]  DROP  CONSTRAINT [Resource_AssignedResource]
34ALTER TABLE [dbo].[AssignedResources]  WITH CHECK ADD  CONSTRAINT [Resource_AssignedResource] FOREIGN KEY([ResourceId])
35REFERENCES [dbo].[Resource] ([ResourceId])
36ON UPDATE CASCADE
37ON DELETE CASCADE
38GO
39
40ALTER TABLE dbo.Job ALTER COLUMN JobId ADD ROWGUIDCOL;
41ALTER TABLE dbo.Job WITH NOCHECK ADD CONSTRAINT [DF_Job_JobId] DEFAULT (newid()) FOR JobId;
42GO
43
44ALTER TABLE [dbo].[StateLog]  DROP  CONSTRAINT [Job_StateLog]
45ALTER TABLE [dbo].[StateLog]  WITH CHECK ADD CONSTRAINT [Job_StateLog] FOREIGN KEY([JobId])
46REFERENCES [dbo].[Job] ([JobId])
47ON UPDATE CASCADE
48ON DELETE CASCADE
49GO
50
51ALTER TABLE dbo.Plugin ALTER COLUMN PluginId ADD ROWGUIDCOL;
52ALTER TABLE dbo.Plugin WITH NOCHECK ADD CONSTRAINT [DF_Plugin_PluginId] DEFAULT (newid()) FOR PluginId;
53
54ALTER TABLE dbo.PluginData ALTER COLUMN PluginDataId ADD ROWGUIDCOL;
55ALTER TABLE dbo.PluginData WITH NOCHECK ADD CONSTRAINT [DF_PluginData_PluginDataId] DEFAULT (newid()) FOR PluginDataId;
56
57ALTER TABLE dbo.RequiredPlugins ALTER COLUMN RequiredPluginId ADD ROWGUIDCOL;
58ALTER TABLE dbo.RequiredPlugins WITH NOCHECK ADD CONSTRAINT [DF_RequiredPlugins_RequiredPluginId] DEFAULT (newid()) FOR RequiredPluginId;
59
60ALTER TABLE [dbo].[RequiredPlugins]  DROP  CONSTRAINT [Job_RequiredPlugin]
61ALTER TABLE [dbo].[RequiredPlugins]  WITH CHECK ADD  CONSTRAINT [Job_RequiredPlugin] FOREIGN KEY([JobId])
62REFERENCES [dbo].[Job] ([JobId])
63ON UPDATE CASCADE
64ON DELETE CASCADE
65GO
66
67ALTER TABLE [dbo].[RequiredPlugins]  DROP  CONSTRAINT [Plugin_RequiredPlugin]
68ALTER TABLE [dbo].[RequiredPlugins]  WITH CHECK ADD  CONSTRAINT [Plugin_RequiredPlugin] FOREIGN KEY([PluginId])
69REFERENCES [dbo].[Plugin] ([PluginId])
70ON UPDATE CASCADE
71ON DELETE CASCADE
72GO
73
74ALTER TABLE dbo.Resource ALTER COLUMN ResourceId ADD ROWGUIDCOL;
75ALTER TABLE dbo.Resource WITH NOCHECK ADD CONSTRAINT [DF_Resource_ResourceId] DEFAULT (newid()) FOR ResourceId;
76
77ALTER TABLE dbo.UptimeCalendar ALTER COLUMN UptimeCalendarId ADD ROWGUIDCOL;
78ALTER TABLE dbo.UptimeCalendar WITH NOCHECK ADD CONSTRAINT [DF_UptimeCalendar_UptimeCalendarId] DEFAULT (newid()) FOR UptimeCalendarId;
79
80ALTER TABLE dbo.HiveExperiment ALTER COLUMN HiveExperimentId ADD ROWGUIDCOL;
81ALTER TABLE dbo.HiveExperiment WITH NOCHECK ADD CONSTRAINT [DF_HiveExperiment_HiveExperimentId] DEFAULT (newid()) FOR HiveExperimentId;
82
83ALTER TABLE dbo.StateLog ALTER COLUMN StateLogId ADD ROWGUIDCOL;
84ALTER TABLE dbo.StateLog WITH NOCHECK ADD CONSTRAINT [DF_StateLog_StateLogId] DEFAULT (newid()) FOR StateLogId;
85
86ALTER TABLE [dbo].[HiveExperimentPermission]  DROP  CONSTRAINT [HiveExperiment_HiveExperimentPermission]
87ALTER TABLE [dbo].[HiveExperimentPermission]  WITH CHECK ADD CONSTRAINT [HiveExperiment_HiveExperimentPermission] FOREIGN KEY([HiveExperimentId])
88REFERENCES [dbo].[HiveExperiment] ([HiveExperimentId])
89ON UPDATE CASCADE
90ON DELETE CASCADE
91GO
92
93/* create indices */
94CREATE INDEX Index_RequiredPlugins_JobId ON RequiredPlugins(JobId);
95
96/* triggers */
97SET ANSI_NULLS ON
98GO
99SET QUOTED_IDENTIFIER ON
100GO
101-- =============================================
102-- Author:    cneumuel
103-- Create date: 11.11.2010
104-- Description: Deletes the root-job of the experiment when experiment is deleted
105-- =============================================
106CREATE TRIGGER [dbo].[tr_HiveExperimentDeleteCascade] ON [dbo].[HiveExperiment] FOR DELETE AS
107SET NOCOUNT ON
108DELETE Job FROM deleted, Job WHERE Job.JobId = deleted.RootJobId
109GO
110
111SET ANSI_NULLS ON
112GO
113SET QUOTED_IDENTIFIER ON
114GO
115-- =============================================
116-- Author:    cneumuel
117-- Create date: 11.11.2010
118-- 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/)
119-- =============================================
120CREATE TRIGGER [dbo].[tr_JobDeleteCascade] ON [dbo].[Job] INSTEAD OF DELETE AS
121BEGIN
122  CREATE TABLE #Table(
123    JobId uniqueidentifier
124  )
125  INSERT INTO #Table (JobId)
126  SELECT JobId FROM deleted
127 
128  DECLARE @c INT
129  SET @c = 0
130 
131  WHILE @c <> (SELECT COUNT(JobId) FROM #Table) BEGIN
132    SELECT @c = COUNT(JobId) FROM #Table
133   
134    INSERT INTO #Table (JobId)
135      SELECT Job.JobId
136      FROM Job
137      LEFT OUTER JOIN #Table ON Job.JobId = #Table.JobId
138      WHERE Job.ParentJobId IN (SELECT JobId FROM #Table)
139        AND #Table.JobId IS NULL
140  END
141 
142  DELETE JobData FROM JobData INNER JOIN #Table ON JobData.JobId = #Table.JobId
143  DELETE Job FROM Job INNER JOIN #Table ON Job.JobId = #Table.JobId
144END
Note: See TracBrowser for help on using the repository browser.