1 | USE [HeuristicLab.Hive-3.3]
|
---|
2 | /* create and initialize hive database tables */
|
---|
3 |
|
---|
4 | EXEC sp_configure filestream_access_level, 2
|
---|
5 | GO
|
---|
6 | RECONFIGURE
|
---|
7 | GO
|
---|
8 |
|
---|
9 | SET ARITHABORT ON
|
---|
10 | CREATE TABLE [dbo].[AssignedResources](
|
---|
11 | [ResourceId] UniqueIdentifier NOT NULL,
|
---|
12 | [TaskId] UniqueIdentifier NOT NULL,
|
---|
13 | CONSTRAINT [PK_dbo.ResourceIdTaskId] PRIMARY KEY ([ResourceId], [TaskId])
|
---|
14 | )
|
---|
15 | CREATE TABLE [dbo].[Plugin](
|
---|
16 | [PluginId] UniqueIdentifier NOT NULL,
|
---|
17 | [Name] VarChar(MAX) NOT NULL,
|
---|
18 | [Version] VarChar(MAX) NOT NULL,
|
---|
19 | [UserId] UniqueIdentifier NOT NULL,
|
---|
20 | [DateCreated] DateTime NOT NULL,
|
---|
21 | [Hash] VarBinary(20) NOT NULL,
|
---|
22 | CONSTRAINT [PK_dbo.Plugin] PRIMARY KEY ([PluginId])
|
---|
23 | )
|
---|
24 | CREATE TABLE [dbo].[RequiredPlugins](
|
---|
25 | [RequiredPluginId] UniqueIdentifier NOT NULL,
|
---|
26 | [TaskId] UniqueIdentifier NOT NULL,
|
---|
27 | [PluginId] UniqueIdentifier NOT NULL,
|
---|
28 | CONSTRAINT [PK_dbo.RequiredPlugins] PRIMARY KEY ([RequiredPluginId])
|
---|
29 | )
|
---|
30 | CREATE TABLE [dbo].[Resource](
|
---|
31 | [ResourceId] UniqueIdentifier NOT NULL,
|
---|
32 | [Name] VarChar(MAX) NOT NULL,
|
---|
33 | [ResourceType] NVarChar(4000) NOT NULL,
|
---|
34 | [ParentResourceId] UniqueIdentifier,
|
---|
35 | [CpuSpeed] Int,
|
---|
36 | [Memory] Int,
|
---|
37 | [Login] DateTime,
|
---|
38 | [SlaveState] VarChar(15),
|
---|
39 | [Cores] Int,
|
---|
40 | [FreeCores] Int,
|
---|
41 | [FreeMemory] Int,
|
---|
42 | [IsAllowedToCalculate] Bit,
|
---|
43 | [CpuArchitecture] VarChar(3),
|
---|
44 | [OperatingSystem] VarChar(MAX),
|
---|
45 | [LastHeartbeat] DateTime,
|
---|
46 | [CpuUtilization] float,
|
---|
47 | [HbInterval] int NOT NULL,
|
---|
48 | [IsDisposable] Bit,
|
---|
49 | [OwnerUserId] UniqueIdentifier,
|
---|
50 | CONSTRAINT [PK_dbo.Resource] PRIMARY KEY ([ResourceId])
|
---|
51 | )
|
---|
52 | CREATE TABLE [dbo].[ResourcePermission](
|
---|
53 | [ResourceId] UniqueIdentifier NOT NULL,
|
---|
54 | [GrantedUserId] UniqueIdentifier NOT NULL,
|
---|
55 | [GrantedByUserId] UniqueIdentifier NOT NULL,
|
---|
56 | CONSTRAINT [PK_dbo.ResourcePermission] PRIMARY KEY ([ResourceId], [GrantedUserId])
|
---|
57 | )
|
---|
58 | CREATE TABLE [dbo].[Task](
|
---|
59 | [TaskId] UniqueIdentifier NOT NULL,
|
---|
60 | [TaskState] VarChar(30) NOT NULL,
|
---|
61 | [ExecutionTimeMs] float NOT NULL,
|
---|
62 | [LastHeartbeat] DateTime,
|
---|
63 | [ParentTaskId] UniqueIdentifier,
|
---|
64 | [Priority] Int NOT NULL,
|
---|
65 | [CoresNeeded] Int NOT NULL,
|
---|
66 | [MemoryNeeded] Int NOT NULL,
|
---|
67 | [IsParentTask] Bit NOT NULL,
|
---|
68 | [FinishWhenChildJobsFinished] Bit NOT NULL,
|
---|
69 | [Command] VarChar(30),
|
---|
70 | [JobId] UniqueIdentifier NOT NULL,
|
---|
71 | [IsPrivileged] Bit NOT NULL,
|
---|
72 | CONSTRAINT [PK_dbo.Task] PRIMARY KEY ([TaskId])
|
---|
73 | )
|
---|
74 | CREATE TABLE [dbo].[Downtime](
|
---|
75 | [DowntimeId] UniqueIdentifier NOT NULL,
|
---|
76 | [ResourceId] UniqueIdentifier NOT NULL,
|
---|
77 | [StartDate] DateTime NOT NULL,
|
---|
78 | [EndDate] DateTime NOT NULL,
|
---|
79 | [AllDayEvent] Bit NOT NULL,
|
---|
80 | [Recurring] Bit NOT NULL,
|
---|
81 | [RecurringId] UniqueIdentifier NOT NULL,
|
---|
82 | [DowntimeType] VarChar(MAX) NOT NULL,
|
---|
83 | CONSTRAINT [PK_dbo.Downtime] PRIMARY KEY ([DowntimeId])
|
---|
84 | )
|
---|
85 | CREATE TABLE [dbo].[Job](
|
---|
86 | [JobId] UniqueIdentifier NOT NULL,
|
---|
87 | [Name] VarChar(MAX) NOT NULL,
|
---|
88 | [Description] VarChar(MAX),
|
---|
89 | [ResourceIds] VarChar(MAX),
|
---|
90 | [OwnerUserId] UniqueIdentifier NOT NULL,
|
---|
91 | [DateCreated] DateTime NOT NULL,
|
---|
92 | CONSTRAINT [PK_dbo.Job] PRIMARY KEY ([JobId])
|
---|
93 | )
|
---|
94 | CREATE TABLE [dbo].[TaskData](
|
---|
95 | [TaskId] UniqueIdentifier RowGuidCol NOT NULL,
|
---|
96 | [Data] VarBinary(MAX) Filestream NOT NULL,
|
---|
97 | [LastUpdate] DateTime NOT NULL,
|
---|
98 | CONSTRAINT [PK_dbo.TaskData] PRIMARY KEY ([TaskId])
|
---|
99 | )
|
---|
100 | CREATE TABLE [dbo].[PluginData](
|
---|
101 | [PluginDataId] UniqueIdentifier RowGuidCol NOT NULL,
|
---|
102 | [PluginId] UniqueIdentifier NOT NULL,
|
---|
103 | [Data] VarBinary(MAX) FileStream NOT NULL,
|
---|
104 | [FileName] VarChar(MAX) NOT NULL,
|
---|
105 | CONSTRAINT [PK_dbo.PluginData] PRIMARY KEY ([PluginDataId])
|
---|
106 | )
|
---|
107 | CREATE TABLE [dbo].[StateLog](
|
---|
108 | [StateLogId] UniqueIdentifier NOT NULL,
|
---|
109 | [State] VarChar(30) NOT NULL,
|
---|
110 | [DateTime] DateTime NOT NULL,
|
---|
111 | [TaskId] UniqueIdentifier NOT NULL,
|
---|
112 | [UserId] UniqueIdentifier,
|
---|
113 | [SlaveId] UniqueIdentifier,
|
---|
114 | [Exception] VarChar(MAX),
|
---|
115 | CONSTRAINT [PK_dbo.StateLog] PRIMARY KEY ([StateLogId])
|
---|
116 | )
|
---|
117 | CREATE TABLE [dbo].[JobPermission](
|
---|
118 | [JobId] UniqueIdentifier NOT NULL,
|
---|
119 | [GrantedUserId] UniqueIdentifier NOT NULL,
|
---|
120 | [GrantedByUserId] UniqueIdentifier NOT NULL,
|
---|
121 | [Permission] VarChar(15) NOT NULL,
|
---|
122 | CONSTRAINT [PK_dbo.JobPermission] PRIMARY KEY ([JobId], [GrantedUserId])
|
---|
123 | )
|
---|
124 | CREATE TABLE [Lifecycle](
|
---|
125 | [LifecycleId] Int NOT NULL,
|
---|
126 | [LastCleanup] DateTime NOT NULL,
|
---|
127 | CONSTRAINT [PK_Lifecycle] PRIMARY KEY ([LifecycleId])
|
---|
128 | )
|
---|
129 | CREATE TABLE [UserPriority](
|
---|
130 | [UserId] UniqueIdentifier NOT NULL,
|
---|
131 | [DateEnqueued] DateTime NOT NULL,
|
---|
132 | CONSTRAINT [PK_UserPriority] PRIMARY KEY ([UserId])
|
---|
133 | )
|
---|
134 | ALTER TABLE [dbo].[AssignedResources]
|
---|
135 | ADD CONSTRAINT [Resource_AssignedResource] FOREIGN KEY ([ResourceId]) REFERENCES [dbo].[Resource]([ResourceId])
|
---|
136 | ALTER TABLE [dbo].[AssignedResources]
|
---|
137 | ADD CONSTRAINT [Task_AssignedResource] FOREIGN KEY ([TaskId]) REFERENCES [dbo].[Task]([TaskId])
|
---|
138 | ALTER TABLE [dbo].[RequiredPlugins]
|
---|
139 | ADD CONSTRAINT [Plugin_RequiredPlugin] FOREIGN KEY ([PluginId]) REFERENCES [dbo].[Plugin]([PluginId])
|
---|
140 | ALTER TABLE [dbo].[RequiredPlugins]
|
---|
141 | ADD CONSTRAINT [Task_RequiredPlugin] FOREIGN KEY ([TaskId]) REFERENCES [dbo].[Task]([TaskId])
|
---|
142 | ALTER TABLE [dbo].[Resource]
|
---|
143 | ADD CONSTRAINT [Resource_Resource] FOREIGN KEY ([ParentResourceId]) REFERENCES [dbo].[Resource]([ResourceId])
|
---|
144 | ALTER TABLE [dbo].[ResourcePermission]
|
---|
145 | ADD CONSTRAINT [Resource_ResourcePermission] FOREIGN KEY ([ResourceId]) REFERENCES [dbo].[Resource]([ResourceId])
|
---|
146 | ALTER TABLE [dbo].[Task]
|
---|
147 | ADD CONSTRAINT [Task_Task] FOREIGN KEY ([ParentTaskId]) REFERENCES [dbo].[Task]([TaskId])
|
---|
148 | ALTER TABLE [dbo].[Task]
|
---|
149 | ADD CONSTRAINT [Job_Job] FOREIGN KEY ([JobId]) REFERENCES [dbo].[Job]([JobId])
|
---|
150 | ALTER TABLE [dbo].[Downtime]
|
---|
151 | ADD CONSTRAINT [Resource_Downtime] FOREIGN KEY ([ResourceId]) REFERENCES [dbo].[Resource]([ResourceId])
|
---|
152 | ALTER TABLE [dbo].[TaskData]
|
---|
153 | ADD CONSTRAINT [Task_TaskData] FOREIGN KEY ([TaskId]) REFERENCES [dbo].[Task]([TaskId])
|
---|
154 | ALTER TABLE [dbo].[PluginData]
|
---|
155 | ADD CONSTRAINT [Plugin_PluginData] FOREIGN KEY ([PluginId]) REFERENCES [dbo].[Plugin]([PluginId])
|
---|
156 | ALTER TABLE [dbo].[StateLog]
|
---|
157 | ADD CONSTRAINT [Task_StateLog] FOREIGN KEY ([TaskId]) REFERENCES [dbo].[Task]([TaskId])
|
---|
158 | ALTER TABLE [dbo].[StateLog]
|
---|
159 | ADD CONSTRAINT [Resource_StateLog] FOREIGN KEY ([SlaveId]) REFERENCES [dbo].[Resource]([ResourceId])
|
---|
160 | ALTER TABLE [dbo].[JobPermission]
|
---|
161 | ADD CONSTRAINT [Job_JobPermission] FOREIGN KEY ([JobId]) REFERENCES [dbo].[Job]([JobId])
|
---|
162 |
|
---|
163 | GO
|
---|
164 | CREATE SCHEMA [statistics]
|
---|
165 | GO
|
---|
166 |
|
---|
167 | CREATE TABLE [statistics].[DimTime] (
|
---|
168 | [Time] DATETIME NOT NULL,
|
---|
169 | [Minute] DATETIME NOT NULL,
|
---|
170 | [Hour] DATETIME NOT NULL,
|
---|
171 | [Day] DATE NOT NULL,
|
---|
172 | [Month] DATE NOT NULL,
|
---|
173 | [Year] DATE NOT NULL,
|
---|
174 | CONSTRAINT [PK_DimTime] PRIMARY KEY CLUSTERED ([Time] ASC)
|
---|
175 | );
|
---|
176 | CREATE TABLE [statistics].[DimClient] (
|
---|
177 | [Id] UNIQUEIDENTIFIER CONSTRAINT [DF_DimClient_Id] DEFAULT (newsequentialid()) NOT NULL,
|
---|
178 | [Name] VARCHAR (MAX) NOT NULL,
|
---|
179 | [ResourceId] UNIQUEIDENTIFIER NOT NULL,
|
---|
180 | [ExpirationTime] DATETIME NULL,
|
---|
181 | [ResourceGroupId] UNIQUEIDENTIFIER NULL,
|
---|
182 | [ResourceGroup2Id] UNIQUEIDENTIFIER NULL,
|
---|
183 | [GroupName] VARCHAR (MAX) NULL,
|
---|
184 | [GroupName2] VARCHAR (MAX) NULL,
|
---|
185 | CONSTRAINT [PK_DimClient] PRIMARY KEY CLUSTERED ([Id] ASC)
|
---|
186 | );
|
---|
187 | CREATE TABLE [statistics].[DimJob] (
|
---|
188 | [JobId] UNIQUEIDENTIFIER NOT NULL,
|
---|
189 | [UserId] UNIQUEIDENTIFIER NOT NULL,
|
---|
190 | [JobName] VARCHAR (MAX) NOT NULL,
|
---|
191 | [UserName] VARCHAR (MAX) NOT NULL,
|
---|
192 | [DateCreated] DATETIME NOT NULL,
|
---|
193 | [TotalTasks] INT NOT NULL,
|
---|
194 | [CompletedTasks] INT NOT NULL,
|
---|
195 | [DateCompleted] DATETIME NULL,
|
---|
196 | CONSTRAINT [PK_DimJob] PRIMARY KEY CLUSTERED ([JobId] ASC)
|
---|
197 | );
|
---|
198 | CREATE TABLE [statistics].[DimUser] (
|
---|
199 | [UserId] UNIQUEIDENTIFIER NOT NULL,
|
---|
200 | [Name] VARCHAR (MAX) NOT NULL,
|
---|
201 | CONSTRAINT [PK_DimUser] PRIMARY KEY CLUSTERED ([UserId] ASC)
|
---|
202 | );
|
---|
203 | CREATE TABLE [statistics].[FactClientInfo] (
|
---|
204 | [ClientId] UNIQUEIDENTIFIER NOT NULL,
|
---|
205 | [Time] DATETIME NOT NULL,
|
---|
206 | [UserId] UNIQUEIDENTIFIER NOT NULL,
|
---|
207 | [NumUsedCores] INT NOT NULL,
|
---|
208 | [NumTotalCores] INT NOT NULL,
|
---|
209 | [UsedMemory] INT NOT NULL,
|
---|
210 | [TotalMemory] INT NOT NULL,
|
---|
211 | [CpuUtilization] FLOAT (53) NOT NULL,
|
---|
212 | [SlaveState] VarChar(15) NOT NULL,
|
---|
213 | [IdleTime] INT NOT NULL,
|
---|
214 | [OfflineTime] INT NOT NULL,
|
---|
215 | [UnavailableTime] INT NOT NULL,
|
---|
216 | [IsAllowedToCalculate] BIT NOT NULL,
|
---|
217 | CONSTRAINT [PK_FactClientInfo] PRIMARY KEY CLUSTERED ([ClientId] ASC, [Time] ASC, [UserId] ASC),
|
---|
218 | CONSTRAINT [FK_FactClientInfo_DimTime] FOREIGN KEY ([Time]) REFERENCES [statistics].[DimTime] ([Time]),
|
---|
219 | CONSTRAINT [FK_FactClientInfo_DimClient] FOREIGN KEY ([ClientId]) REFERENCES [statistics].[DimClient] ([Id]),
|
---|
220 | CONSTRAINT [FK_FactClientInfo_DimUser] FOREIGN KEY ([UserId]) REFERENCES [statistics].[DimUser] ([UserId])
|
---|
221 | );
|
---|
222 | CREATE TABLE [statistics].[FactTask] (
|
---|
223 | [TaskId] UNIQUEIDENTIFIER NOT NULL,
|
---|
224 | [CalculatingTime] INT NOT NULL,
|
---|
225 | [WaitingTime] INT NOT NULL,
|
---|
226 | [TransferTime] INT NOT NULL,
|
---|
227 | [NumCalculationRuns] INT NOT NULL,
|
---|
228 | [NumRetries] INT NOT NULL,
|
---|
229 | [CoresRequired] INT NOT NULL,
|
---|
230 | [MemoryRequired] INT NOT NULL,
|
---|
231 | [Priority] INT NOT NULL,
|
---|
232 | [LastClientId] UNIQUEIDENTIFIER NULL,
|
---|
233 | [JobId] UNIQUEIDENTIFIER NOT NULL,
|
---|
234 | [StartTime] DATETIME NULL,
|
---|
235 | [EndTime] DATETIME NULL,
|
---|
236 | [TaskState] VARCHAR (30) NOT NULL,
|
---|
237 | [Exception] VARCHAR (MAX) NULL,
|
---|
238 | [InitialWaitingTime] INT NULL,
|
---|
239 | CONSTRAINT [PK_FactTask] PRIMARY KEY CLUSTERED ([TaskId] ASC),
|
---|
240 | CONSTRAINT [FK_FactTask_DimClient] FOREIGN KEY ([LastClientId]) REFERENCES [statistics].[DimClient] ([Id]),
|
---|
241 | CONSTRAINT [FK_FactTask_DimJob] FOREIGN KEY ([JobId]) REFERENCES [statistics].[DimJob] ([JobId])
|
---|
242 | );
|
---|
243 |
|
---|
244 | /* dummy for nullable userIds in FactClientInfo */
|
---|
245 | INSERT INTO [statistics].[DimUser] ([UserId], [Name])
|
---|
246 | VALUES ('00000000-0000-0000-0000-000000000000', 'NULL'); |
---|