Hadoop-Metrics-SQLServer-CREATE.ddl 27 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296297298299300301302303304305306307308309310311312313314315316317318319320321322323324325326327328329330331332333334335336337338339340341342343344345346347348349350351352353354355356357358359360361362363364365366367368369370371372373374375376377378379380381382383384385386387388389390391392393394395396397398399400401402403404405406407408409410411412413414415416417418419420421422423424425426427428429430431432433434435436437438439440441442443444445446447448449450451452453454455456457458459460461462463464465466467468469470471472473474475476477478479480481482483484485486487488489490491492493494495496497498499500501502503504505506507508509510511512513514515516517518519520521522523524525526527528529530531532533534535536537538539540541542543544545546547548549550551552553554555556557558559560561562563564565566567568569570571572573574575576577578579580581582583584585586587588589590591592593594595596597598599600601602603604605606607608609610611612613614615616617618619620621622623624625626627628629630631632633634635636637638639640641642643644645646647648649650651652653654655656657658659660661662663664665666667668669670671672673674675676677678679680681682683684685686687688689690691692693694695696697698699700701702703704705706707708709710711712713714715716717718719720721722723724725726727728729730731732733734735736737738739740741742743744745746747748749750751752753754755756757758759760761762763764765766767768769770771772773774775776777778779780781782783784785786787788789790791792793
  1. /*
  2. Licensed to the Apache Software Foundation (ASF) under one
  3. or more contributor license agreements. See the NOTICE file
  4. distributed with this work for additional information
  5. regarding copyright ownership. The ASF licenses this file
  6. to you under the Apache License, Version 2.0 (the
  7. "License"); you may not use this file except in compliance
  8. with the License. You may obtain a copy of the License at
  9. http://www.apache.org/licenses/LICENSE-2.0
  10. Unless required by applicable law or agreed to in writing, software
  11. distributed under the License is distributed on an "AS IS" BASIS,
  12. WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied.
  13. See the License for the specific language governing permissions and
  14. limitations under the License.
  15. */
  16. /*
  17. Deployment script for HadoopMetrics
  18. */
  19. USE [master]
  20. GO
  21. IF db_id('HadoopMetrics') IS NOT NULL
  22. BEGIN
  23. Print N'Dropping [dbo].[HadoopMetrics] database...'
  24. DROP DATABASE HadoopMetrics
  25. END
  26. GO
  27. Print N'Creating [dbo].[HadoopMetrics] database...'
  28. CREATE DATABASE [HadoopMetrics]
  29. GO
  30. USE [HadoopMetrics]
  31. GO
  32. SET QUOTED_IDENTIFIER ON;
  33. GO
  34. IF NOT EXISTS(SELECT name FROM sys.objects WHERE name = N'CompletedJob' and type_desc = N'USER_TABLE')
  35. BEGIN
  36. PRINT N'Creating [dbo].[CompletedJob]...';
  37. CREATE TABLE [dbo].[CompletedJob] (
  38. [ClusterNodeID] INT NOT NULL,
  39. [TagSetID] INT NOT NULL,
  40. [MapProgressPercent] INT NOT NULL,
  41. [CleanupProgressPercent] INT NOT NULL,
  42. [SetupProgressPercent] INT NOT NULL,
  43. [ReduceProgressPercent] INT NOT NULL,
  44. [RunState] INT NOT NULL,
  45. [StartTime] DATETIME NOT NULL,
  46. [EndTime] DATETIME NOT NULL
  47. );
  48. END
  49. GO
  50. IF NOT EXISTS(SELECT name FROM sys.indexes WHERE name = N'PK_CompletedJob_ClusterNodeID_TagSetID' AND type_desc = N'CLUSTERED' AND IS_PRIMARY_KEY=N'1')
  51. BEGIN
  52. PRINT N'Creating [dbo].[CompletedJob].[PK_CompletedJob_ClusterNodeID_TagSetID]...';
  53. ALTER TABLE [dbo].[CompletedJob]
  54. ADD CONSTRAINT [PK_CompletedJob_ClusterNodeID_TagSetID] PRIMARY KEY CLUSTERED ([ClusterNodeID] ASC, [TagSetID] ASC);
  55. END
  56. GO
  57. IF NOT EXISTS(SELECT name FROM sys.indexes WHERE name = N'IX_CompletedJob_EndTime' AND type_desc = N'NONCLUSTERED')
  58. BEGIN
  59. PRINT N'Creating [dbo].[CompletedJob].[IX_CompletedJob_EndTime]...';
  60. CREATE NONCLUSTERED INDEX [IX_CompletedJob_EndTime]
  61. ON [dbo].[CompletedJob]([EndTime] ASC) ;
  62. END
  63. GO
  64. IF NOT EXISTS(SELECT name FROM sys.indexes WHERE name = N'IX_CompletedJob_TagSetID' AND type_desc = N'NONCLUSTERED')
  65. BEGIN
  66. PRINT N'Creating [dbo].[CompletedJob].[IX_CompletedJob_TagSetID]...';
  67. CREATE NONCLUSTERED INDEX [IX_CompletedJob_TagSetID]
  68. ON [dbo].[CompletedJob]([TagSetID] ASC) ;
  69. END
  70. GO
  71. IF NOT EXISTS(SELECT name FROM sys.objects WHERE name = N'Configuration' and type_desc = N'USER_TABLE')
  72. BEGIN
  73. PRINT N'Creating [dbo].[Configuration]...';
  74. CREATE TABLE [dbo].[Configuration] (
  75. [RequestedRefreshRate] INT NOT NULL
  76. );
  77. END
  78. GO
  79. IF NOT EXISTS(SELECT name FROM sys.objects WHERE name = N'DatabaseVersion' and type_desc = N'USER_TABLE')
  80. BEGIN
  81. PRINT N'Creating [dbo].[DatabaseVersion]...';
  82. CREATE TABLE [dbo].[DatabaseVersion] (
  83. [Major] INT NOT NULL,
  84. [Minor] INT NOT NULL,
  85. [Build] INT NOT NULL,
  86. [Revision] INT NOT NULL
  87. );
  88. END
  89. GO
  90. IF NOT EXISTS(SELECT name FROM sys.objects WHERE name = N'MetricName' and type_desc = N'USER_TABLE')
  91. BEGIN
  92. PRINT N'Creating [dbo].[MetricName]...';
  93. CREATE TABLE [dbo].[MetricName] (
  94. [MetricID] INT IDENTITY (1, 1) NOT NULL,
  95. [Name] NVARCHAR (256) NOT NULL,
  96. PRIMARY KEY CLUSTERED ([MetricID] ASC)
  97. );
  98. END
  99. GO
  100. IF NOT EXISTS(SELECT name FROM sys.indexes WHERE name = N'IX_MetricName_Name' AND type_desc = N'NONCLUSTERED')
  101. BEGIN
  102. PRINT N'Creating [dbo].[MetricName].[IX_MetricName_Name]...';
  103. CREATE UNIQUE NONCLUSTERED INDEX [IX_MetricName_Name]
  104. ON [dbo].[MetricName]([Name] ASC) ;
  105. END
  106. GO
  107. IF NOT EXISTS(SELECT name FROM sys.objects WHERE name = N'MetricPair' and type_desc = N'USER_TABLE')
  108. BEGIN
  109. PRINT N'Creating [dbo].[MetricPair]...';
  110. CREATE TABLE [dbo].[MetricPair] (
  111. [RecordID] BIGINT NOT NULL,
  112. [MetricID] INT NOT NULL,
  113. [MetricValue] NVARCHAR (512) NOT NULL
  114. );
  115. END
  116. GO
  117. IF NOT EXISTS(SELECT name FROM sys.indexes WHERE name = N'UX_MetricPair_RecordID_MetricID' AND type_desc = N'CLUSTERED')
  118. BEGIN
  119. PRINT N'Creating [dbo].[MetricPair].[UX_MetricPair_RecordID_MetricID]...';
  120. CREATE UNIQUE CLUSTERED INDEX [UX_MetricPair_RecordID_MetricID]
  121. ON [dbo].[MetricPair]([RecordID] ASC, [MetricID] ASC) ;
  122. END
  123. GO
  124. IF NOT EXISTS(SELECT name FROM sys.objects WHERE name = N'MetricRecord' and type_desc = N'USER_TABLE')
  125. BEGIN
  126. PRINT N'Creating [dbo].[MetricRecord]...';
  127. CREATE TABLE [dbo].[MetricRecord] (
  128. [RecordID] BIGINT IDENTITY (1, 1) NOT NULL,
  129. [RecordTypeID] INT NOT NULL,
  130. [NodeID] INT NOT NULL,
  131. [SourceIP] NVARCHAR (256) NULL,
  132. [ClusterNodeID] INT NOT NULL,
  133. [ServiceID] INT NOT NULL,
  134. [TagSetID] INT NOT NULL,
  135. [RecordTimestamp] BIGINT NOT NULL,
  136. [RecordDate] AS DATEADD(second, CONVERT (INT, RecordTimestamp / 1000), CONVERT (DATETIME, '1970-01-01T00:00:00.000', 126)) PERSISTED,
  137. PRIMARY KEY CLUSTERED ([RecordID] ASC)
  138. );
  139. END
  140. GO
  141. IF NOT EXISTS(SELECT name FROM sys.indexes WHERE name = N'IX_MetricRecord_ClusterNodeID' AND type_desc = N'NONCLUSTERED')
  142. BEGIN
  143. PRINT N'Creating [dbo].[MetricRecord].[IX_MetricRecord_ClusterNodeID]...';
  144. CREATE NONCLUSTERED INDEX [IX_MetricRecord_ClusterNodeID]
  145. ON [dbo].[MetricRecord]([ClusterNodeID] ASC) ;
  146. END
  147. GO
  148. IF NOT EXISTS(SELECT name FROM sys.indexes WHERE name = N'IX_MetricRecord_NodeID_RecordID' AND type_desc = N'NONCLUSTERED')
  149. BEGIN
  150. PRINT N'Creating [dbo].[MetricRecord].[IX_MetricRecord_NodeID_RecordID]...';
  151. CREATE NONCLUSTERED INDEX [IX_MetricRecord_NodeID_RecordID]
  152. ON [dbo].[MetricRecord]([NodeID] ASC, [RecordID] ASC) ;
  153. END
  154. GO
  155. IF NOT EXISTS(SELECT name FROM sys.indexes WHERE name = N'IX_MetricRecord_NodeID_RecordTypeID_ClusterNodeID' AND type_desc = N'NONCLUSTERED')
  156. BEGIN
  157. PRINT N'Creating [dbo].[MetricRecord].[IX_MetricRecord_NodeID_RecordTypeID_ClusterNodeID]...';
  158. CREATE NONCLUSTERED INDEX [IX_MetricRecord_NodeID_RecordTypeID_ClusterNodeID]
  159. ON [dbo].[MetricRecord]([NodeID] ASC, [RecordTypeID] ASC, [ClusterNodeID] ASC)
  160. INCLUDE([RecordDate]) ;
  161. END
  162. GO
  163. IF NOT EXISTS(SELECT name FROM sys.indexes WHERE name = N'IX_MetricRecord_NodeID_TagSetID' AND type_desc = N'NONCLUSTERED')
  164. BEGIN
  165. PRINT N'Creating [dbo].[MetricRecord].[IX_MetricRecord_NodeID_TagSetID]...';
  166. CREATE NONCLUSTERED INDEX [IX_MetricRecord_NodeID_TagSetID]
  167. ON [dbo].[MetricRecord]([NodeID] ASC, [TagSetID] ASC) ;
  168. END
  169. GO
  170. IF NOT EXISTS(SELECT name FROM sys.indexes WHERE name = N'IX_MetricRecord_RecordDate' AND type_desc = N'NONCLUSTERED')
  171. BEGIN
  172. PRINT N'Creating [dbo].[MetricRecord].[IX_MetricRecord_RecordDate]...';
  173. CREATE NONCLUSTERED INDEX [IX_MetricRecord_RecordDate]
  174. ON [dbo].[MetricRecord]([RecordDate] ASC) ;
  175. END
  176. GO
  177. IF NOT EXISTS(SELECT name FROM sys.indexes WHERE name = N'IX_MetricRecord_RecordTimestamp_NodeID_RecordTypeID' AND type_desc = N'NONCLUSTERED')
  178. BEGIN
  179. PRINT N'Creating [dbo].[MetricRecord].[IX_MetricRecord_RecordTimestamp_NodeID_RecordTypeID]...';
  180. CREATE NONCLUSTERED INDEX [IX_MetricRecord_RecordTimestamp_NodeID_RecordTypeID]
  181. ON [dbo].[MetricRecord]([RecordTimestamp] DESC, [NodeID] ASC, [RecordTypeID] ASC)
  182. INCLUDE([RecordID]) ;
  183. END
  184. GO
  185. IF NOT EXISTS(SELECT name FROM sys.indexes WHERE name = N'IX_MetricRecord_RecordTypeID' AND type_desc = N'NONCLUSTERED')
  186. BEGIN
  187. PRINT N'Creating [dbo].[MetricRecord].[IX_MetricRecord_RecordTypeID]...';
  188. CREATE NONCLUSTERED INDEX [IX_MetricRecord_RecordTypeID]
  189. ON [dbo].[MetricRecord]([RecordTypeID] ASC) ;
  190. END
  191. GO
  192. IF NOT EXISTS(SELECT name FROM sys.indexes WHERE name = N'IX_MetricRecord_RecordTypeID_ClusterNodeID_ServiceID_TagSetID_RecordTimestamp' AND type_desc = N'NONCLUSTERED')
  193. BEGIN
  194. PRINT N'Creating [dbo].[MetricRecord].[IX_MetricRecord_RecordTypeID_ClusterNodeID_ServiceID_TagSetID_RecordTimestamp]...';
  195. CREATE NONCLUSTERED INDEX [IX_MetricRecord_RecordTypeID_ClusterNodeID_ServiceID_TagSetID_RecordTimestamp]
  196. ON [dbo].[MetricRecord]([RecordTypeID] ASC, [ClusterNodeID] ASC, [ServiceID] ASC, [TagSetID] ASC, [RecordTimestamp] DESC) ;
  197. END
  198. GO
  199. IF NOT EXISTS(SELECT name FROM sys.indexes WHERE name = N'IX_MetricRecord_TagSetID' AND type_desc = N'NONCLUSTERED')
  200. BEGIN
  201. PRINT N'Creating [dbo].[MetricRecord].[IX_MetricRecord_TagSetID]...';
  202. CREATE NONCLUSTERED INDEX [IX_MetricRecord_TagSetID]
  203. ON [dbo].[MetricRecord]([TagSetID] ASC) ;
  204. END
  205. GO
  206. IF NOT EXISTS(SELECT name FROM sys.indexes WHERE name = N'UX_MetricRecord_RecordTypeID_NodeID_TagSetID_RecordTimestamp' AND type_desc = N'NONCLUSTERED')
  207. BEGIN
  208. PRINT N'Creating [dbo].[MetricRecord].[UX_MetricRecord_RecordTypeID_NodeID_TagSetID_RecordTimestamp]...';
  209. CREATE UNIQUE NONCLUSTERED INDEX [UX_MetricRecord_RecordTypeID_NodeID_TagSetID_RecordTimestamp]
  210. ON [dbo].[MetricRecord]([RecordTypeID] ASC, [NodeID] ASC, [TagSetID] ASC, [RecordTimestamp] ASC) ;
  211. END
  212. GO
  213. IF NOT EXISTS(SELECT name FROM sys.objects WHERE name = N'Service' and type_desc = N'USER_TABLE')
  214. BEGIN
  215. PRINT N'Creating [dbo].[Service]...';
  216. CREATE TABLE [dbo].[Service] (
  217. [ServiceID] BIGINT IDENTITY (1, 1) NOT NULL,
  218. [Name] NVARCHAR (256),
  219. PRIMARY KEY CLUSTERED ([ServiceID] ASC)
  220. );
  221. END
  222. GO
  223. IF NOT EXISTS(SELECT name FROM sys.objects WHERE name = N'Node' and type_desc = N'USER_TABLE')
  224. BEGIN
  225. PRINT N'Creating [dbo].[Node]...';
  226. CREATE TABLE [dbo].[Node] (
  227. [NodeID] INT IDENTITY (1, 1) NOT NULL,
  228. [Name] NVARCHAR (256) NOT NULL,
  229. [LastKnownIP] NVARCHAR (256) NULL,
  230. [LastNameNodeHeartBeat] DATETIME NULL,
  231. [LastJobTrackerHeartBeat] DATETIME NULL,
  232. [LastDataNodeHeartBeat] DATETIME NULL,
  233. [LastTaskTrackerHeartBeat] DATETIME NULL,
  234. PRIMARY KEY CLUSTERED ([NodeID] ASC)
  235. );
  236. END
  237. GO
  238. IF NOT EXISTS(SELECT name FROM sys.indexes WHERE name = N'IX_Node_Name' AND type_desc = N'NONCLUSTERED')
  239. BEGIN
  240. PRINT N'Creating [dbo].[Node].[IX_Node_Name]...';
  241. CREATE UNIQUE NONCLUSTERED INDEX [IX_Node_Name]
  242. ON [dbo].[Node]([Name] ASC) ;
  243. END
  244. GO
  245. IF NOT EXISTS(SELECT name FROM sys.objects WHERE name = N'RecordType' and type_desc = N'USER_TABLE')
  246. BEGIN
  247. PRINT N'Creating [dbo].[RecordType]...';
  248. CREATE TABLE [dbo].[RecordType] (
  249. [RecordTypeID] INT IDENTITY (1, 1) NOT NULL,
  250. [Name] NVARCHAR (256) NOT NULL,
  251. [Context] NVARCHAR (256) NOT NULL,
  252. PRIMARY KEY CLUSTERED ([RecordTypeID] ASC)
  253. );
  254. END
  255. GO
  256. IF NOT EXISTS(SELECT name FROM sys.indexes WHERE name = N'IX_RecordType_Context_Name' AND type_desc = N'NONCLUSTERED')
  257. BEGIN
  258. PRINT N'Creating [dbo].[RecordType].[IX_RecordType_Context_Name]...';
  259. CREATE UNIQUE NONCLUSTERED INDEX [IX_RecordType_Context_Name]
  260. ON [dbo].[RecordType]([Context] ASC, [Name] ASC) ;
  261. END
  262. GO
  263. IF NOT EXISTS(SELECT name FROM sys.objects WHERE name = N'TagSet' and type_desc = N'USER_TABLE')
  264. BEGIN
  265. PRINT N'Creating [dbo].[TagSet]...';
  266. CREATE TABLE [dbo].[TagSet] (
  267. [TagSetID] INT IDENTITY (1, 1) NOT NULL,
  268. [TagPairs] NVARCHAR (512) NOT NULL,
  269. PRIMARY KEY CLUSTERED ([TagSetID] ASC)
  270. );
  271. END
  272. GO
  273. IF NOT EXISTS(SELECT name FROM sys.indexes WHERE name = N'IX_TagSet_TagPairs' AND type_desc = N'NONCLUSTERED')
  274. BEGIN
  275. PRINT N'Creating [dbo].[TagSet].[IX_TagSet_TagPairs]...';
  276. CREATE UNIQUE NONCLUSTERED INDEX [IX_TagSet_TagPairs]
  277. ON [dbo].[TagSet]([TagPairs] ASC) ;
  278. END
  279. GO
  280. IF NOT EXISTS (SELECT name FROM sys.foreign_keys WHERE name = N'FK_CompletedJob_TagSet_TagSetID')
  281. BEGIN
  282. PRINT N'Creating FK_CompletedJob_TagSet_TagSetID...';
  283. ALTER TABLE [dbo].[CompletedJob] WITH NOCHECK
  284. ADD CONSTRAINT [FK_CompletedJob_TagSet_TagSetID] FOREIGN KEY ([TagSetID]) REFERENCES [dbo].[TagSet] ([TagSetID]) ON DELETE NO ACTION ON UPDATE NO ACTION;
  285. END
  286. GO
  287. IF NOT EXISTS (SELECT name FROM sys.foreign_keys WHERE name = N'FK_MetricPair_MetricName_MetricID')
  288. BEGIN
  289. PRINT N'Creating FK_MetricPair_MetricName_MetricID...';
  290. ALTER TABLE [dbo].[MetricPair] WITH NOCHECK
  291. ADD CONSTRAINT [FK_MetricPair_MetricName_MetricID] FOREIGN KEY ([MetricID]) REFERENCES [dbo].[MetricName] ([MetricID]) ON DELETE NO ACTION ON UPDATE NO ACTION;
  292. END
  293. GO
  294. IF NOT EXISTS (SELECT name FROM sys.foreign_keys WHERE name = N'FK_MetricPair_MetricRecord_RecordID')
  295. BEGIN
  296. PRINT N'Creating FK_MetricPair_MetricRecord_RecordID...';
  297. ALTER TABLE [dbo].[MetricPair] WITH NOCHECK
  298. ADD CONSTRAINT [FK_MetricPair_MetricRecord_RecordID] FOREIGN KEY ([RecordID]) REFERENCES [dbo].[MetricRecord] ([RecordID]) ON DELETE NO ACTION ON UPDATE NO ACTION;
  299. END
  300. GO
  301. IF NOT EXISTS (SELECT name FROM sys.foreign_keys WHERE name = N'FK_MetricRecord_Node_NodeID')
  302. BEGIN
  303. PRINT N'Creating FK_MetricRecord_Node_NodeID...';
  304. ALTER TABLE [dbo].[MetricRecord] WITH NOCHECK
  305. ADD CONSTRAINT [FK_MetricRecord_Node_NodeID] FOREIGN KEY ([NodeID]) REFERENCES [dbo].[Node] ([NodeID]) ON DELETE NO ACTION ON UPDATE NO ACTION;
  306. END
  307. GO
  308. IF NOT EXISTS (SELECT name FROM sys.foreign_keys WHERE name = N'FK_MetricRecord_RecordType_RecordTypeID')
  309. BEGIN
  310. PRINT N'Creating FK_MetricRecord_RecordType_RecordTypeID...';
  311. ALTER TABLE [dbo].[MetricRecord] WITH NOCHECK
  312. ADD CONSTRAINT [FK_MetricRecord_RecordType_RecordTypeID] FOREIGN KEY ([RecordTypeID]) REFERENCES [dbo].[RecordType] ([RecordTypeID]) ON DELETE NO ACTION ON UPDATE NO ACTION;
  313. END
  314. GO
  315. IF NOT EXISTS (SELECT name FROM sys.foreign_keys WHERE name = N'FK_MetricRecord_TagSet_TagSetID')
  316. BEGIN
  317. PRINT N'Creating FK_MetricRecord_TagSet_TagSetID...';
  318. ALTER TABLE [dbo].[MetricRecord] WITH NOCHECK
  319. ADD CONSTRAINT [FK_MetricRecord_TagSet_TagSetID] FOREIGN KEY ([TagSetID]) REFERENCES [dbo].[TagSet] ([TagSetID]) ON DELETE NO ACTION ON UPDATE NO ACTION;
  320. END
  321. GO
  322. IF NOT EXISTS(SELECT name FROM sys.objects WHERE name = N'uspInsertMetricValue' and type_desc = N'SQL_STORED_PROCEDURE')
  323. BEGIN
  324. PRINT N'Creating [dbo].[uspInsertMetricValue]...';
  325. exec('CREATE PROCEDURE [dbo].[uspInsertMetricValue]
  326. @recordID bigint,
  327. @metricName nvarchar(256),
  328. @metricValue nvarchar(512)
  329. AS
  330. BEGIN
  331. SET NOCOUNT ON;
  332. DECLARE @metricID int;
  333. DECLARE @err int;
  334. IF @recordID IS NULL OR @metricName IS NULL RETURN;
  335. BEGIN TRANSACTION;
  336. SELECT @metricID = MetricID FROM MetricName WHERE Name = @metricName;
  337. IF @metricID IS NULL
  338. BEGIN
  339. INSERT INTO MetricName (Name) VALUES (@metricName);
  340. SELECT @err = @@ERROR, @metricID = SCOPE_IDENTITY();
  341. IF @err <> 0 GOTO Abort;
  342. END
  343. COMMIT TRANSACTION;
  344. INSERT INTO MetricPair (RecordID, MetricID, MetricValue) VALUES (@recordID, @metricID, @metricValue);
  345. RETURN;
  346. Abort:
  347. ROLLBACK TRANSACTION;
  348. RETURN;
  349. END')
  350. END
  351. GO
  352. IF NOT EXISTS(SELECT name FROM sys.objects WHERE name = N'uspUpdateHeartBeats' and type_desc = N'SQL_STORED_PROCEDURE')
  353. BEGIN
  354. PRINT N'Creating [dbo].[uspUpdateHeartBeats]...';
  355. exec('CREATE PROCEDURE [dbo].[uspUpdateHeartBeats]
  356. @NodeID int,
  357. @SourceIP nvarchar(256),
  358. @NameNodeLast datetime,
  359. @JobTrackerLast datetime,
  360. @DataNodeLast datetime,
  361. @TaskTrackerLast datetime,
  362. @LastKnownIP nvarchar(256)
  363. AS
  364. BEGIN
  365. IF @NodeID IS NOT NULL
  366. BEGIN
  367. IF @NameNodeLast IS NOT NULL
  368. BEGIN
  369. UPDATE Node SET LastNameNodeHeartBeat = @NameNodeLast WHERE NodeID = @NodeID;
  370. END
  371. IF @JobTrackerLast IS NOT NULL
  372. BEGIN
  373. UPDATE Node SET LastJobTrackerHeartBeat = @JobTrackerLast WHERE NodeID = @NodeID;
  374. END
  375. IF @DataNodeLast IS NOT NULL
  376. BEGIN
  377. UPDATE Node SET LastDataNodeHeartBeat = @DataNodeLast WHERE NodeID = @NodeID;
  378. END
  379. IF @TaskTrackerLast IS NOT NULL
  380. BEGIN
  381. UPDATE Node SET LastTaskTrackerHeartBeat = @TaskTrackerLast WHERE NodeID = @NodeID;
  382. END
  383. IF @LastKnownIP IS NULL OR @SourceIP <> @LastKnownIP
  384. BEGIN
  385. UPDATE Node SET LastKnownIP = @SourceIP WHERE NodeID = @NodeID;
  386. END
  387. END
  388. END')
  389. END
  390. GO
  391. IF NOT EXISTS(SELECT name FROM sys.objects WHERE name = N'uspGetMetricRecord' and type_desc = N'SQL_STORED_PROCEDURE')
  392. BEGIN
  393. PRINT N'Creating [dbo].[uspGetMetricRecord]...';
  394. exec('CREATE PROCEDURE [dbo].[uspGetMetricRecord]
  395. @recordTypeContext nvarchar(256),
  396. @recordTypeName nvarchar(256),
  397. @nodeName nvarchar(256),
  398. @sourceIP nvarchar(256),
  399. @clusterNodeName nvarchar(256),
  400. @serviceName nvarchar(256),
  401. @tagPairs nvarchar(512),
  402. @recordTimestamp bigint,
  403. @metricRecordID bigint OUTPUT
  404. AS
  405. BEGIN
  406. SET NOCOUNT ON;
  407. DECLARE @recordTypeID int
  408. DECLARE @nodeID int
  409. DECLARE @clusterNodeID int
  410. DECLARE @tagSetID int
  411. DECLARE @serviceID int
  412. DECLARE @err int
  413. DECLARE @recordIDCutoff bigint
  414. BEGIN TRANSACTION;
  415. SELECT @recordTypeID = RecordTypeID FROM RecordType WHERE Context = @recordTypeContext AND Name = @recordTypeName;
  416. IF @recordTypeID IS NULL
  417. BEGIN
  418. INSERT INTO RecordType (Context, Name) VALUES (@recordTypeContext, @recordTypeName);
  419. SELECT @err = @@ERROR, @recordTypeID = SCOPE_IDENTITY();
  420. IF @err <> 0 GOTO Abort;
  421. END
  422. COMMIT TRANSACTION;
  423. BEGIN TRANSACTION;
  424. SELECT @serviceID = serviceID FROM Service WHERE Name = @serviceName;
  425. IF @serviceID IS NULL
  426. BEGIN
  427. INSERT INTO Service (Name) VALUES (@serviceName);
  428. SELECT @err = @@ERROR, @serviceID = SCOPE_IDENTITY();
  429. IF @err <> 0 GOTO Abort;
  430. END
  431. COMMIT TRANSACTION;
  432. BEGIN TRANSACTION;
  433. SELECT @nodeID = NodeID FROM Node WHERE Name = @nodeName;
  434. IF @nodeID IS NULL
  435. BEGIN
  436. /* Start with a node type of uninitialized. HealthNode will determine node type based on metrics delivered over time. */
  437. INSERT INTO Node (Name, LastKnownIP) VALUES (@nodeName, @sourceIP);
  438. SELECT @err = @@ERROR, @nodeID = SCOPE_IDENTITY();
  439. IF @err <> 0 GOTO Abort;
  440. END
  441. COMMIT TRANSACTION;
  442. -- Do our best to determine the cluster node ID based on completely flakey input from user which might be an IP address, a non-FQDN,
  443. -- or an FQDN. Note that worker nodes may have a completely different idea about the name of the namenode (which is the node
  444. -- which represents the cluster) compared with the namenode itself
  445. BEGIN TRANSACTION;
  446. IF ((SELECT [dbo].[ufnIsIPAddress](@clusterNodeName)) = 1)
  447. BEGIN
  448. SELECT TOP 1 @clusterNodeID = NodeID from Node WHERE LastKnownIP = @clusterNodeName ORDER BY LastNameNodeHeartBeat DESC;
  449. IF @clusterNodeID IS NULL
  450. BEGIN
  451. INSERT INTO Node (Name, LastKnownIP) VALUES (@clusterNodeName, @sourceIP);
  452. SELECT @err = @@ERROR, @clusterNodeID = SCOPE_IDENTITY();
  453. IF @err <> 0 GOTO Abort;
  454. END
  455. END
  456. ELSE
  457. IF ((SELECT CHARINDEX(@clusterNodeName, ''.'', 1)) > 0)
  458. BEGIN
  459. -- IF this is not an IP address, but there is a dot in the name we assume we are looking at an FQDN
  460. SELECT @clusterNodeID = NodeID FROM Node WHERE Name = @clusterNodeName;
  461. IF @clusterNodeID IS NULL
  462. BEGIN
  463. INSERT INTO Node (Name, LastKnownIP) VALUES (@clusterNodeName, @sourceIP);
  464. SELECT @err = @@ERROR, @clusterNodeID = SCOPE_IDENTITY();
  465. IF @err <> 0 GOTO Abort;
  466. END
  467. END
  468. ELSE
  469. BEGIN
  470. -- We have got a non-FQDN, but the NameNode might know its FQDN, so be careful! We must prefer the FQDN if we can find one.
  471. -- Sadly, yes, this could break things if we are monitoring clusters from different domains. This is now by design!
  472. SELECT TOP 1 @clusterNodeID = NodeID FROM Node WHERE Name LIKE @clusterNodeName + ''.%'' ORDER BY LastNameNodeHeartBeat DESC;
  473. IF @clusterNodeID IS NULL
  474. BEGIN
  475. SELECT @clusterNodeID = NodeID FROM Node WHERE Name = @clusterNodeName;
  476. if @clusterNodeID IS NULL
  477. BEGIN
  478. INSERT INTO Node (Name, LastKnownIP) VALUES (@clusterNodeName, @sourceIP);
  479. SELECT @err = @@ERROR, @clusterNodeID = SCOPE_IDENTITY();
  480. IF @err <> 0 GOTO Abort;
  481. END
  482. END
  483. END
  484. COMMIT TRANSACTION;
  485. -- Cleanup older metric records and pairs if necessary
  486. -- Policy is to keep between 60000 and 90000 metric records and associated metric pairs per node.
  487. IF (SELECT COUNT(*) FROM MetricRecord WHERE NodeID = @nodeID) > 90000
  488. BEGIN
  489. SELECT @recordIDCutoff = MIN(RecordID) FROM MetricRecord WHERE RecordID IN (SELECT TOP 60000 RecordID FROM MetricRecord WHERE NodeID = @nodeID ORDER BY RecordDate DESC);
  490. IF @recordIDCutoff IS NOT NULL
  491. BEGIN
  492. DELETE FROM MetricPair
  493. FROM MetricPair as mp
  494. JOIN MetricRecord as mr ON mp.RecordID = mr.RecordID
  495. WHERE mr.RecordID < @recordIDCutoff AND mr.NodeID = @nodeID;
  496. DELETE FROM MetricRecord
  497. WHERE RecordID < @recordIDCutoff AND NodeID = @nodeID;
  498. END;
  499. END;
  500. BEGIN TRANSACTION;
  501. SELECT @tagSetID = TagSetID FROM TagSet WHERE TagPairs = @tagPairs;
  502. IF @tagSetID IS NULL
  503. BEGIN
  504. INSERT INTO TagSet (TagPairs) VALUES (@tagPairs);
  505. SELECT @err = @@ERROR, @tagSetID = SCOPE_IDENTITY();
  506. IF @err <> 0 GOTO Abort;
  507. END
  508. COMMIT TRANSACTION;
  509. BEGIN TRANSACTION;
  510. SELECT @metricRecordID = RecordID FROM MetricRecord WHERE RecordTypeID = @recordTypeID AND NodeID = @nodeID AND ServiceID = @serviceID AND TagSetID = @tagSetID AND RecordTimestamp = @recordTimestamp;
  511. IF @metricRecordID IS NULL
  512. BEGIN
  513. INSERT INTO MetricRecord (RecordTypeID, NodeID, SourceIP, ClusterNodeID, ServiceID, TagSetID, RecordTimestamp) VALUES (@recordTypeID, @nodeID, @sourceIP, @clusterNodeID, @serviceID, @tagSetID, @recordTimestamp);
  514. SELECT @err = @@ERROR, @metricRecordID = SCOPE_IDENTITY();
  515. IF @err <> 0 GOTO Abort;
  516. END
  517. COMMIT TRANSACTION;
  518. GOTO Success;
  519. Abort:
  520. ROLLBACK TRANSACTION;
  521. SET @metricRecordID = NULL;
  522. RETURN;
  523. Success:
  524. RETURN;
  525. END')
  526. END
  527. GO
  528. IF NOT EXISTS(SELECT name FROM sys.objects WHERE name = N'ufnIsIPAddress' and type_desc = N'SQL_SCALAR_FUNCTION')
  529. BEGIN
  530. PRINT N'Creating [dbo].[ufnIsIPAddress]...';
  531. exec('CREATE FUNCTION [dbo].[ufnIsIPAddress]
  532. (
  533. @inputString nvarchar(max)
  534. )
  535. RETURNS BIT
  536. AS
  537. BEGIN
  538. DECLARE @currentPos bigint = 1;
  539. DECLARE @nextPos bigint = 0;
  540. DECLARE @count int = 0;
  541. if (LEN(@inputString) = 0) RETURN 0;
  542. SELECT @nextPos = CHARINDEX(''.'', @inputString, @currentPos);
  543. WHILE (@nextPos < LEN(@inputString) AND @count < 4)
  544. BEGIN
  545. IF (@nextPos = 0) SET @nextPos = LEN(@inputString);
  546. IF ((SELECT ISNUMERIC(SUBSTRING(@inputString, @currentPos, @nextPos - @currentPos))) = 1)
  547. BEGIN
  548. SET @count = @count + 1;
  549. SET @currentPos = @nextPos
  550. SELECT @nextPos = CHARINDEX(''.'', @inputString, @currentPos + 1);
  551. END
  552. ELSE BREAK;
  553. END
  554. IF (@count = 4) RETURN 1;
  555. SET @currentPos = 1;
  556. SET @nextPos = 0;
  557. SET @count = 0;
  558. WHILE (@currentPos <= LEN(@inputString))
  559. BEGIN
  560. IF EXISTS (SELECT 1 WHERE SUBSTRING(@inputString, @currentPos, 1) LIKE ''[0-9A-Fa-f:]'')
  561. BEGIN
  562. IF (SUBSTRING(@inputString, @currentPos, 1) = N'':'') SET @count = @count + 1;
  563. SET @currentPos = @currentPos + 1;
  564. END
  565. ELSE RETURN 0;
  566. END
  567. IF @count >= 4 return 1;
  568. RETURN 0;
  569. END')
  570. END
  571. GO
  572. IF NOT EXISTS(SELECT name FROM sys.objects WHERE name = N'RethrowError' and type_desc = N'SQL_STORED_PROCEDURE')
  573. BEGIN
  574. PRINT N'Creating Stored Proc: [dbo].[RethrowError]...';
  575. exec('CREATE PROCEDURE [dbo].[RethrowError]
  576. AS
  577. BEGIN
  578. DECLARE @ErrorMessage NVARCHAR(4000);
  579. DECLARE @ErrorSeverity INT;
  580. DECLARE @ErrorState INT;
  581. SELECT
  582. @ErrorMessage = ERROR_MESSAGE(),
  583. @ErrorSeverity = ERROR_SEVERITY(),
  584. @ErrorState = ERROR_STATE();
  585. RAISERROR (@ErrorMessage, -- Message text.
  586. @ErrorSeverity, -- Severity.
  587. @ErrorState -- State.
  588. );
  589. END
  590. ')
  591. END
  592. IF NOT EXISTS(SELECT name FROM sys.objects WHERE name = N'uspPurgeMetrics' and type_desc = N'SQL_STORED_PROCEDURE')
  593. BEGIN
  594. -- purge metrics older than @noOfDays
  595. PRINT N'Creating [dbo].[uspPurgeMetrics]...';
  596. exec('CREATE PROCEDURE [dbo].[uspPurgeMetrics]
  597. @noOfDays bigint
  598. AS
  599. BEGIN
  600. IF @noOfDays IS NULL OR @noOfDays < 1
  601. BEGIN
  602. RAISERROR(''INVALID_ARGUMENT'', 15, 1)
  603. RETURN
  604. END;
  605. DECLARE @recordIDCutOff BIGINT
  606. SELECT @recordIDCutoff = MAX(RecordID) FROM MetricRecord WHERE DateDiff(day, RecordDate, CURRENT_TIMESTAMP) >= @noOfDays
  607. IF @recordIDCutoff IS NOT NULL
  608. BEGIN
  609. BEGIN TRY
  610. BEGIN TRANSACTION
  611. DELETE FROM MetricPair WHERE RecordID <= @recordIDCutoff
  612. DELETE FROM MetricRecord WHERE RecordID <= @recordIDCutoff
  613. IF @@TRANCOUNT > 0
  614. BEGIN
  615. COMMIT TRANSACTION
  616. END
  617. END TRY
  618. BEGIN CATCH
  619. IF @@TRANCOUNT > 0
  620. BEGIN
  621. ROLLBACK TRANSACTION;
  622. END
  623. -- get error infromation and raise error
  624. EXECUTE [dbo].[RethrowError]
  625. RETURN
  626. END CATCH
  627. END;
  628. END');
  629. END
  630. IF NOT EXISTS(SELECT name FROM sys.objects WHERE name = N'ufGetMetrics' and type_desc = N'SQL_STORED_PROCEDURE')
  631. BEGIN
  632. PRINT N'Creating [dbo].[ufGetMetrics]...';
  633. exec( 'CREATE FUNCTION dbo.ufGetMetrics
  634. (@startTimeStamp bigint,
  635. @endTimeStamp bigint,
  636. @recordTypeContext NVARCHAR(256),
  637. @recordTypeName NVARCHAR(256),
  638. @metricName NVARCHAR(256),
  639. @serviceComponentName NVARCHAR(256),
  640. @nodeName NVARCHAR(256)
  641. )
  642. RETURNS TABLE --(MetricTimeStamp bigint, MetricValue NVARCHAR(512))
  643. AS
  644. RETURN
  645. (
  646. SELECT s.RecordTimeStamp AS RecordTimeStamp,
  647. mp.MetricValue AS MetricValue
  648. FROM MetricPair mp
  649. INNER JOIN (SELECT mr.RecordID AS RecordID,
  650. mr.RecordTimeStamp AS RecordTimeStamp
  651. FROM MetricRecord mr
  652. INNER JOIN RecordType rt ON (mr.RecordTypeId = rt.RecordTypeId)
  653. INNER JOIN Node nd ON (mr.NodeID = nd.NodeID)
  654. INNER JOIN Service sr ON (mr.ServiceID = sr.ServiceID)
  655. WHERE rt.Context = @recordTypeContext
  656. AND rt.Name = @recordTypeName
  657. AND (nd.Name = @nodeName)
  658. AND (sr.Name = @serviceComponentName)
  659. AND mr.RecordTimestamp >= @startTimeStamp
  660. AND mr.RecordTimestamp <= @endTimeStamp
  661. ) s ON (mp.RecordID = s.RecordID)
  662. INNER JOIN MetricName mn ON (mp.MetricID = mn.MetricID)
  663. WHERE (mn.Name = @metricName)
  664. )'
  665. )
  666. END
  667. GO
  668. IF NOT EXISTS(SELECT name FROM sys.objects WHERE name = N'ufGetAggregatedServiceMetrics' and type_desc = N'SQL_STORED_PROCEDURE')
  669. BEGIN
  670. PRINT N'Creating [dbo].[ufGetAggregatedServiceMetrics]...';
  671. exec( 'CREATE FUNCTION [dbo].[ufGetAggregatedServiceMetrics]
  672. (@startTimeStamp bigint,
  673. @endTimeStamp bigint,
  674. @recordTypeContext NVARCHAR(256),
  675. @recordTypeName NVARCHAR(256),
  676. @metricName NVARCHAR(256),
  677. @serviceComponentName NVARCHAR(256),
  678. @period integer
  679. )
  680. RETURNS TABLE ----(TimeStampBlock integer, MetricTimeStamp bigint, MetricValue NVARCHAR(512))
  681. AS
  682. RETURN
  683. (
  684. SELECT FLOOR ((mr.RecordTimeStamp - @startTimeStamp) / @period) TimeStampBlock, MAX(mr.RecordTimeStamp) RecordTimeStamp, SUM(CONVERT(NUMERIC(18,4), MetricValue)) AggMetricValue
  685. FROM MetricPair mp
  686. INNER JOIN MetricRecord mr ON (mp.RecordID = mr.RecordID)
  687. INNER JOIN RecordType rt ON (rt.RecordTypeID = mr.RecordTypeID)
  688. INNER JOIN MetricName mn ON (mn.MetricID = mp.MetricID)
  689. INNER JOIN Service sr ON (sr.ServiceID = mr.ServiceID)
  690. WHERE mr.RecordTimestamp >= @startTimeStamp
  691. AND mr.RecordTimestamp <= @endTimeStamp
  692. AND mn.Name = @metricName
  693. AND rt.Context = @recordTypeContext
  694. AND rt.Name = @recordTypeName
  695. AND sr.Name = @serviceComponentName
  696. GROUP BY FLOOR ((mr.RecordTimeStamp - @startTimeStamp) / @period)
  697. )'
  698. )
  699. END
  700. GO