Ambari-DDL-SQLServer-CREATE.sql 39 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296297298299300301302303304305306307308309310311312313314315316317318319320321322323324325326327328329330331332333334335336337338339340341342343344345346347348349350351352353354355356357358359360361362363364365366367368369370371372373374375376377378379380381382383384385386387388389390391392393394395396397398399400401402403404405406407408409410411412413414415416417418419420421422423424425426427428429430431432433434435436437438439440441442443444445446447448449450451452453454455456457458459460461462463464465466467468469470471472473474475476477478479480481482483484485486487488489490491492493494495496497498499500501502503504505506507508509510511512513514515516517518519520521522523524525526527528529530531532533534535536537538539540541542543544545546547548549550551552553554555556557558559560561562563564565566567568569570571572573574575576577578579580581582583584585586587588589590591592593594595596597598599600601602603604605606607608609610611612613614615616617618619620621622623624625626627628629630631632633634635636637638639640641642643644645646647648649650651652653654655656657658659660661662663664665666667668669670671672673674675676677678679680681682683684685686687688689690691692693694695696697698699700701702703704705706707708709710711712713714715716717718719720721722723724
  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. Schema population script for $(AMBARIDBNAME)
  18. Use this script in sqlcmd mode, setting the environment variables like this:
  19. set AMBARIDBNAME=ambari
  20. sqlcmd -S localhost\SQLEXPRESS -i C:\app\ambari-server-1.3.0-SNAPSHOT\resources\Ambari-DDL-SQLServer-CREATE.sql
  21. */
  22. use [$(AMBARIDBNAME)]
  23. GO
  24. ------create the database------
  25. ------create tables and grant privileges to db user---------
  26. CREATE TABLE clusters (cluster_id BIGINT NOT NULL, resource_id BIGINT NOT NULL, cluster_info VARCHAR(255) NOT NULL, cluster_name VARCHAR(100) NOT NULL UNIQUE, provisioning_state VARCHAR(255) NOT NULL DEFAULT 'INIT', desired_cluster_state VARCHAR(255) NOT NULL, desired_stack_version VARCHAR(255) NOT NULL, PRIMARY KEY CLUSTERED (cluster_id));
  27. CREATE TABLE clusterconfig (config_id BIGINT NOT NULL, version_tag VARCHAR(255) NOT NULL, version BIGINT NOT NULL, type_name VARCHAR(255) NOT NULL, cluster_id BIGINT NOT NULL, config_data VARCHAR(MAX) NOT NULL, config_attributes VARCHAR(MAX), create_timestamp BIGINT NOT NULL, PRIMARY KEY CLUSTERED (config_id));
  28. CREATE TABLE serviceconfig (service_config_id BIGINT NOT NULL, cluster_id BIGINT NOT NULL, service_name VARCHAR(255) NOT NULL, version BIGINT NOT NULL, create_timestamp BIGINT NOT NULL, user_name VARCHAR(255) NOT NULL DEFAULT '_db', group_id BIGINT, note VARCHAR(MAX), PRIMARY KEY CLUSTERED (service_config_id));
  29. CREATE TABLE serviceconfighosts (service_config_id BIGINT NOT NULL, hostname VARCHAR(255) NOT NULL, PRIMARY KEY CLUSTERED (service_config_id, hostname));
  30. CREATE TABLE serviceconfigmapping (service_config_id BIGINT NOT NULL, config_id BIGINT NOT NULL, PRIMARY KEY CLUSTERED (service_config_id, config_id));
  31. CREATE TABLE clusterconfigmapping (cluster_id BIGINT NOT NULL, type_name VARCHAR(255) NOT NULL, version_tag VARCHAR(255) NOT NULL, create_timestamp BIGINT NOT NULL, selected INTEGER NOT NULL DEFAULT 0, user_name VARCHAR(255) NOT NULL DEFAULT '_db', PRIMARY KEY CLUSTERED (cluster_id, type_name, create_timestamp));
  32. CREATE TABLE clusterservices (service_name VARCHAR(255) NOT NULL, cluster_id BIGINT NOT NULL, service_enabled INTEGER NOT NULL, PRIMARY KEY CLUSTERED (service_name, cluster_id));
  33. CREATE TABLE clusterstate (cluster_id BIGINT NOT NULL, current_cluster_state VARCHAR(255) NOT NULL, current_stack_version VARCHAR(255) NOT NULL, PRIMARY KEY CLUSTERED (cluster_id));
  34. CREATE TABLE hostcomponentdesiredstate (cluster_id BIGINT NOT NULL, component_name VARCHAR(255) NOT NULL, desired_stack_version VARCHAR(255) NOT NULL, desired_state VARCHAR(255) NOT NULL, host_name VARCHAR(255) NOT NULL, service_name VARCHAR(255) NOT NULL, admin_state VARCHAR(32), maintenance_state VARCHAR(32) NOT NULL, restart_required BIT NOT NULL DEFAULT 0, PRIMARY KEY CLUSTERED (cluster_id, component_name, host_name, service_name));
  35. CREATE TABLE hostcomponentstate (cluster_id BIGINT NOT NULL, component_name VARCHAR(255) NOT NULL, current_stack_version VARCHAR(255) NOT NULL, current_state VARCHAR(255) NOT NULL, host_name VARCHAR(255) NOT NULL, service_name VARCHAR(255) NOT NULL, PRIMARY KEY CLUSTERED (cluster_id, component_name, host_name, service_name));
  36. CREATE TABLE hosts (host_name VARCHAR(255) NOT NULL, cpu_count INTEGER NOT NULL, ph_cpu_count INTEGER, cpu_info VARCHAR(255) NOT NULL, discovery_status VARCHAR(2000) NOT NULL, host_attributes VARCHAR(MAX) NOT NULL, ipv4 VARCHAR(255), ipv6 VARCHAR(255), public_host_name VARCHAR(255), last_registration_time BIGINT NOT NULL, os_arch VARCHAR(255) NOT NULL, os_info VARCHAR(1000) NOT NULL, os_type VARCHAR(255) NOT NULL, rack_info VARCHAR(255) NOT NULL, total_mem BIGINT NOT NULL, PRIMARY KEY CLUSTERED (host_name));
  37. CREATE TABLE hoststate (agent_version VARCHAR(255) NOT NULL, available_mem BIGINT NOT NULL, current_state VARCHAR(255) NOT NULL, health_status VARCHAR(255), host_name VARCHAR(255) NOT NULL, time_in_state BIGINT NOT NULL, maintenance_state VARCHAR(512), PRIMARY KEY CLUSTERED (host_name));
  38. CREATE TABLE servicecomponentdesiredstate (component_name VARCHAR(255) NOT NULL, cluster_id BIGINT NOT NULL, desired_stack_version VARCHAR(255) NOT NULL, desired_state VARCHAR(255) NOT NULL, service_name VARCHAR(255) NOT NULL, PRIMARY KEY CLUSTERED (component_name, cluster_id, service_name));
  39. CREATE TABLE servicedesiredstate (cluster_id BIGINT NOT NULL, desired_host_role_mapping INTEGER NOT NULL, desired_stack_version VARCHAR(255) NOT NULL, desired_state VARCHAR(255) NOT NULL, service_name VARCHAR(255) NOT NULL, maintenance_state VARCHAR(32) NOT NULL, PRIMARY KEY CLUSTERED (cluster_id, service_name));
  40. CREATE TABLE users (user_id INTEGER, principal_id BIGINT NOT NULL, ldap_user INTEGER NOT NULL DEFAULT 0, user_name VARCHAR(255) NOT NULL, create_time DATETIME DEFAULT GETDATE(), user_password VARCHAR(255), active INTEGER NOT NULL DEFAULT 1, PRIMARY KEY CLUSTERED (user_id), UNIQUE (ldap_user, user_name));
  41. CREATE TABLE groups (group_id INTEGER, principal_id BIGINT NOT NULL, group_name VARCHAR(255) NOT NULL, ldap_group INTEGER NOT NULL DEFAULT 0, PRIMARY KEY (group_id));
  42. CREATE TABLE members (member_id INTEGER, group_id INTEGER NOT NULL, user_id INTEGER NOT NULL, PRIMARY KEY (member_id));
  43. CREATE TABLE execution_command (command VARBINARY(8000), task_id BIGINT NOT NULL, PRIMARY KEY CLUSTERED (task_id));
  44. CREATE TABLE host_role_command (task_id BIGINT NOT NULL, attempt_count SMALLINT NOT NULL, event VARCHAR(MAX) NOT NULL, exitcode INTEGER NOT NULL, host_name VARCHAR(255) NOT NULL, last_attempt_time BIGINT NOT NULL, request_id BIGINT NOT NULL, role VARCHAR(255), stage_id BIGINT NOT NULL, start_time BIGINT NOT NULL, end_time BIGINT, status VARCHAR(255), std_error VARBINARY(max), std_out VARBINARY(max), output_log VARCHAR(255) NULL, error_log VARCHAR(255) NULL, structured_out VARBINARY(max), role_command VARCHAR(255), command_detail VARCHAR(255), custom_command_name VARCHAR(255), PRIMARY KEY CLUSTERED (task_id));
  45. CREATE TABLE role_success_criteria (role VARCHAR(255) NOT NULL, request_id BIGINT NOT NULL, stage_id BIGINT NOT NULL, success_factor FLOAT NOT NULL, PRIMARY KEY CLUSTERED (role, request_id, stage_id));
  46. CREATE TABLE stage (stage_id BIGINT NOT NULL, request_id BIGINT NOT NULL, cluster_id BIGINT NOT NULL, log_info VARCHAR(255) NOT NULL, request_context VARCHAR(255), cluster_host_info VARBINARY(8000) NOT NULL, command_params VARBINARY(8000), host_params VARBINARY(8000), PRIMARY KEY CLUSTERED (stage_id, request_id));
  47. CREATE TABLE request (request_id BIGINT NOT NULL, cluster_id BIGINT, command_name VARCHAR(255), create_time BIGINT NOT NULL, end_time BIGINT NOT NULL, exclusive_execution BIT NOT NULL DEFAULT 0, inputs VARBINARY(8000), request_context VARCHAR(255), request_type VARCHAR(255), request_schedule_id BIGINT, start_time BIGINT NOT NULL, status VARCHAR(255), PRIMARY KEY CLUSTERED (request_id));
  48. CREATE TABLE requestresourcefilter (filter_id BIGINT NOT NULL, request_id BIGINT NOT NULL, service_name VARCHAR(255), component_name VARCHAR(255), hosts VARBINARY(8000), PRIMARY KEY CLUSTERED (filter_id));
  49. CREATE TABLE requestoperationlevel (operation_level_id BIGINT NOT NULL, request_id BIGINT NOT NULL, level_name VARCHAR(255), cluster_name VARCHAR(255), service_name VARCHAR(255), host_component_name VARCHAR(255), host_name VARCHAR(255), PRIMARY KEY CLUSTERED (operation_level_id));
  50. CREATE TABLE ClusterHostMapping (cluster_id BIGINT NOT NULL, host_name VARCHAR(255) NOT NULL, PRIMARY KEY CLUSTERED (cluster_id, host_name));
  51. CREATE TABLE key_value_store ([key] VARCHAR(255), [value] VARCHAR(MAX), PRIMARY KEY CLUSTERED ([key]));
  52. CREATE TABLE hostconfigmapping (cluster_id BIGINT NOT NULL, host_name VARCHAR(255) NOT NULL, type_name VARCHAR(255) NOT NULL, version_tag VARCHAR(255) NOT NULL, service_name VARCHAR(255), create_timestamp BIGINT NOT NULL, selected INTEGER NOT NULL DEFAULT 0, user_name VARCHAR(255) NOT NULL DEFAULT '_db', PRIMARY KEY CLUSTERED (cluster_id, host_name, type_name, create_timestamp));
  53. CREATE TABLE metainfo ([metainfo_key] VARCHAR(255), [metainfo_value] VARCHAR(255), PRIMARY KEY CLUSTERED ([metainfo_key]));
  54. CREATE TABLE ambari_sequences (sequence_name VARCHAR(255) PRIMARY KEY, [sequence_value] BIGINT NOT NULL);
  55. CREATE TABLE configgroup (group_id BIGINT, cluster_id BIGINT NOT NULL, group_name VARCHAR(255) NOT NULL, tag VARCHAR(1024) NOT NULL, description VARCHAR(1024), create_timestamp BIGINT NOT NULL, service_name VARCHAR(255), PRIMARY KEY(group_id));
  56. CREATE TABLE confgroupclusterconfigmapping (config_group_id BIGINT NOT NULL, cluster_id BIGINT NOT NULL, config_type VARCHAR(255) NOT NULL, version_tag VARCHAR(255) NOT NULL, user_name VARCHAR(255) DEFAULT '_db', create_timestamp BIGINT NOT NULL, PRIMARY KEY(config_group_id, cluster_id, config_type));
  57. CREATE TABLE configgrouphostmapping (config_group_id BIGINT NOT NULL, host_name VARCHAR(255) NOT NULL, PRIMARY KEY(config_group_id, host_name));
  58. CREATE TABLE requestschedule (schedule_id bigint, cluster_id bigint NOT NULL, description varchar(255), status varchar(255), batch_separation_seconds smallint, batch_toleration_limit smallint, create_user varchar(255), create_timestamp bigint, update_user varchar(255), update_timestamp bigint, minutes varchar(10), hours varchar(10), days_of_month varchar(10), month varchar(10), day_of_week varchar(10), yearToSchedule varchar(10), startTime varchar(50), endTime varchar(50), last_execution_status varchar(255), PRIMARY KEY(schedule_id));
  59. CREATE TABLE requestschedulebatchrequest (schedule_id bigint, batch_id bigint, request_id bigint, request_type varchar(255), request_uri varchar(1024), request_body VARBINARY(8000), request_status varchar(255), return_code smallint, return_message text, PRIMARY KEY(schedule_id, batch_id));
  60. CREATE TABLE blueprint (blueprint_name VARCHAR(255) NOT NULL, stack_name VARCHAR(255) NOT NULL, stack_version VARCHAR(255) NOT NULL, PRIMARY KEY(blueprint_name));
  61. CREATE TABLE hostgroup (blueprint_name VARCHAR(255) NOT NULL, name VARCHAR(255) NOT NULL, cardinality VARCHAR(255) NOT NULL, PRIMARY KEY(blueprint_name, name));
  62. CREATE TABLE hostgroup_component (blueprint_name VARCHAR(255) NOT NULL, hostgroup_name VARCHAR(255) NOT NULL, name VARCHAR(255) NOT NULL, PRIMARY KEY(blueprint_name, hostgroup_name, name));
  63. CREATE TABLE blueprint_configuration (blueprint_name varchar(255) NOT NULL, type_name varchar(255) NOT NULL, config_data text NOT NULL, config_attributes VARCHAR(8000), PRIMARY KEY(blueprint_name, type_name));
  64. CREATE TABLE hostgroup_configuration (blueprint_name VARCHAR(255) NOT NULL, hostgroup_name VARCHAR(255) NOT NULL, type_name VARCHAR(255) NOT NULL, config_data TEXT NOT NULL, config_attributes TEXT, PRIMARY KEY(blueprint_name, hostgroup_name, type_name));
  65. CREATE TABLE viewmain (view_name VARCHAR(255) NOT NULL, label VARCHAR(255), description VARCHAR(2048), version VARCHAR(255), resource_type_id INTEGER NOT NULL, icon VARCHAR(255), icon64 VARCHAR(255), archive VARCHAR(255), mask VARCHAR(255), system_view BIT NOT NULL DEFAULT 0, PRIMARY KEY(view_name));
  66. CREATE TABLE viewinstancedata (view_instance_id BIGINT, view_name VARCHAR(255) NOT NULL, view_instance_name VARCHAR(255) NOT NULL, name VARCHAR(255) NOT NULL, user_name VARCHAR(255) NOT NULL, value VARCHAR(2000) NOT NULL, PRIMARY KEY(view_instance_id, name, user_name));
  67. CREATE TABLE viewinstance (view_instance_id BIGINT, resource_id BIGINT NOT NULL, view_name VARCHAR(255) NOT NULL, name VARCHAR(255) NOT NULL, label VARCHAR(255), description VARCHAR(2048), visible CHAR(1), icon VARCHAR(255), icon64 VARCHAR(255), xml_driven CHAR(1), PRIMARY KEY(view_instance_id));
  68. CREATE TABLE viewinstanceproperty (view_name VARCHAR(255) NOT NULL, view_instance_name VARCHAR(255) NOT NULL, name VARCHAR(255) NOT NULL, value VARCHAR(2000) NOT NULL, PRIMARY KEY(view_name, view_instance_name, name));
  69. CREATE TABLE viewparameter (view_name VARCHAR(255) NOT NULL, name VARCHAR(255) NOT NULL, description VARCHAR(2048), required CHAR(1), masked CHAR(1), PRIMARY KEY(view_name, name));
  70. CREATE TABLE viewresource (view_name VARCHAR(255) NOT NULL, name VARCHAR(255) NOT NULL, plural_name VARCHAR(255), id_property VARCHAR(255), subResource_names VARCHAR(255), provider VARCHAR(255), service VARCHAR(255), resource VARCHAR(255), PRIMARY KEY(view_name, name));
  71. CREATE TABLE viewentity (id BIGINT NOT NULL, view_name VARCHAR(255) NOT NULL, view_instance_name VARCHAR(255) NOT NULL, class_name VARCHAR(255) NOT NULL, id_property VARCHAR(255), PRIMARY KEY(id));
  72. CREATE TABLE adminresourcetype (resource_type_id INTEGER NOT NULL, resource_type_name VARCHAR(255) NOT NULL, PRIMARY KEY(resource_type_id));
  73. CREATE TABLE adminresource (resource_id BIGINT NOT NULL, resource_type_id INTEGER NOT NULL, PRIMARY KEY(resource_id));
  74. CREATE TABLE adminprincipaltype (principal_type_id INTEGER NOT NULL, principal_type_name VARCHAR(255) NOT NULL, PRIMARY KEY(principal_type_id));
  75. CREATE TABLE adminprincipal (principal_id BIGINT NOT NULL, principal_type_id INTEGER NOT NULL, PRIMARY KEY(principal_id));
  76. CREATE TABLE adminpermission (permission_id BIGINT NOT NULL, permission_name VARCHAR(255) NOT NULL, resource_type_id INTEGER NOT NULL, PRIMARY KEY(permission_id));
  77. CREATE TABLE adminprivilege (privilege_id BIGINT, permission_id BIGINT NOT NULL, resource_id BIGINT NOT NULL, principal_id BIGINT NOT NULL, PRIMARY KEY(privilege_id));
  78. -- altering tables by creating unique constraints----------
  79. --------altering tables to add constraints----------
  80. ALTER TABLE users ADD CONSTRAINT UNQ_users_0 UNIQUE (user_name, ldap_user);
  81. ALTER TABLE groups ADD CONSTRAINT UNQ_groups_0 UNIQUE (group_name, ldap_group);
  82. ALTER TABLE members ADD CONSTRAINT UNQ_members_0 UNIQUE (group_id, user_id);
  83. ALTER TABLE clusterconfig ADD CONSTRAINT UQ_config_type_tag UNIQUE (cluster_id, type_name, version_tag);
  84. ALTER TABLE clusterconfig ADD CONSTRAINT UQ_config_type_version UNIQUE (cluster_id, type_name, version);
  85. ALTER TABLE viewinstance ADD CONSTRAINT UQ_viewinstance_name UNIQUE (view_name, name);
  86. ALTER TABLE viewinstance ADD CONSTRAINT UQ_viewinstance_name_id UNIQUE (view_instance_id, view_name, name);
  87. ALTER TABLE serviceconfig ADD CONSTRAINT UQ_scv_service_version UNIQUE (cluster_id, service_name, version);
  88. ALTER TABLE adminpermission ADD CONSTRAINT UQ_perm_name_resource_type_id UNIQUE (permission_name, resource_type_id);
  89. -- altering tables by creating foreign keys----------
  90. ALTER TABLE members ADD CONSTRAINT FK_members_group_id FOREIGN KEY (group_id) REFERENCES groups (group_id);
  91. ALTER TABLE members ADD CONSTRAINT FK_members_user_id FOREIGN KEY (user_id) REFERENCES users (user_id);
  92. ALTER TABLE clusterconfig ADD CONSTRAINT FK_clusterconfig_cluster_id FOREIGN KEY (cluster_id) REFERENCES clusters (cluster_id);
  93. ALTER TABLE clusterservices ADD CONSTRAINT FK_clusterservices_cluster_id FOREIGN KEY (cluster_id) REFERENCES clusters (cluster_id);
  94. ALTER TABLE clusterconfigmapping ADD CONSTRAINT clusterconfigmappingcluster_id FOREIGN KEY (cluster_id) REFERENCES clusters (cluster_id);
  95. ALTER TABLE clusterstate ADD CONSTRAINT FK_clusterstate_cluster_id FOREIGN KEY (cluster_id) REFERENCES clusters (cluster_id);
  96. ALTER TABLE hostcomponentdesiredstate ADD CONSTRAINT hstcmponentdesiredstatehstname FOREIGN KEY (host_name) REFERENCES hosts (host_name);
  97. ALTER TABLE hostcomponentdesiredstate ADD CONSTRAINT hstcmpnntdesiredstatecmpnntnme FOREIGN KEY (component_name, cluster_id, service_name) REFERENCES servicecomponentdesiredstate (component_name, cluster_id, service_name);
  98. ALTER TABLE hostcomponentstate ADD CONSTRAINT hstcomponentstatecomponentname FOREIGN KEY (component_name, cluster_id, service_name) REFERENCES servicecomponentdesiredstate (component_name, cluster_id, service_name);
  99. ALTER TABLE hostcomponentstate ADD CONSTRAINT hostcomponentstate_host_name FOREIGN KEY (host_name) REFERENCES hosts (host_name);
  100. ALTER TABLE hoststate ADD CONSTRAINT FK_hoststate_host_name FOREIGN KEY (host_name) REFERENCES hosts (host_name);
  101. ALTER TABLE servicecomponentdesiredstate ADD CONSTRAINT srvccmponentdesiredstatesrvcnm FOREIGN KEY (service_name, cluster_id) REFERENCES clusterservices (service_name, cluster_id);
  102. ALTER TABLE servicedesiredstate ADD CONSTRAINT servicedesiredstateservicename FOREIGN KEY (service_name, cluster_id) REFERENCES clusterservices (service_name, cluster_id);
  103. ALTER TABLE execution_command ADD CONSTRAINT FK_execution_command_task_id FOREIGN KEY (task_id) REFERENCES host_role_command (task_id);
  104. ALTER TABLE host_role_command ADD CONSTRAINT FK_host_role_command_stage_id FOREIGN KEY (stage_id, request_id) REFERENCES stage (stage_id, request_id);
  105. ALTER TABLE host_role_command ADD CONSTRAINT FK_host_role_command_host_name FOREIGN KEY (host_name) REFERENCES hosts (host_name);
  106. ALTER TABLE role_success_criteria ADD CONSTRAINT role_success_criteria_stage_id FOREIGN KEY (stage_id, request_id) REFERENCES stage (stage_id, request_id);
  107. ALTER TABLE stage ADD CONSTRAINT FK_stage_request_id FOREIGN KEY (request_id) REFERENCES request (request_id);
  108. ALTER TABLE request ADD CONSTRAINT FK_request_schedule_id FOREIGN KEY (request_schedule_id) REFERENCES requestschedule (schedule_id);
  109. ALTER TABLE ClusterHostMapping ADD CONSTRAINT ClusterHostMapping_cluster_id FOREIGN KEY (host_name) REFERENCES hosts (host_name);
  110. ALTER TABLE ClusterHostMapping ADD CONSTRAINT ClusterHostMapping_host_name FOREIGN KEY (cluster_id) REFERENCES clusters (cluster_id);
  111. ALTER TABLE hostconfigmapping ADD CONSTRAINT FK_hostconfmapping_cluster_id FOREIGN KEY (cluster_id) REFERENCES clusters (cluster_id);
  112. ALTER TABLE hostconfigmapping ADD CONSTRAINT FK_hostconfmapping_host_name FOREIGN KEY (host_name) REFERENCES hosts (host_name);
  113. ALTER TABLE serviceconfigmapping ADD CONSTRAINT FK_scvm_scv FOREIGN KEY (service_config_id) REFERENCES serviceconfig(service_config_id);
  114. ALTER TABLE serviceconfigmapping ADD CONSTRAINT FK_scvm_config FOREIGN KEY (config_id) REFERENCES clusterconfig(config_id);
  115. ALTER TABLE serviceconfighosts ADD CONSTRAINT FK_scvhosts_scv FOREIGN KEY (service_config_id) REFERENCES serviceconfig(service_config_id);
  116. ALTER TABLE configgroup ADD CONSTRAINT FK_configgroup_cluster_id FOREIGN KEY (cluster_id) REFERENCES clusters (cluster_id);
  117. ALTER TABLE confgroupclusterconfigmapping ADD CONSTRAINT FK_confg FOREIGN KEY (cluster_id, config_type, version_tag) REFERENCES clusterconfig (cluster_id, type_name, version_tag);
  118. ALTER TABLE confgroupclusterconfigmapping ADD CONSTRAINT FK_cgccm_gid FOREIGN KEY (config_group_id) REFERENCES configgroup (group_id);
  119. ALTER TABLE configgrouphostmapping ADD CONSTRAINT FK_cghm_cgid FOREIGN KEY (config_group_id) REFERENCES configgroup (group_id);
  120. ALTER TABLE configgrouphostmapping ADD CONSTRAINT FK_cghm_hname FOREIGN KEY (host_name) REFERENCES hosts (host_name);
  121. ALTER TABLE requestschedulebatchrequest ADD CONSTRAINT FK_rsbatchrequest_schedule_id FOREIGN KEY (schedule_id) REFERENCES requestschedule (schedule_id);
  122. ALTER TABLE hostgroup ADD CONSTRAINT FK_hg_blueprint_name FOREIGN KEY (blueprint_name) REFERENCES blueprint(blueprint_name);
  123. ALTER TABLE hostgroup_component ADD CONSTRAINT FK_hgc_blueprint_name FOREIGN KEY (blueprint_name, hostgroup_name) REFERENCES hostgroup (blueprint_name, name);
  124. ALTER TABLE blueprint_configuration ADD CONSTRAINT FK_cfg_blueprint_name FOREIGN KEY (blueprint_name) REFERENCES blueprint(blueprint_name);
  125. ALTER TABLE hostgroup_configuration ADD CONSTRAINT FK_hg_cfg_bp_hg_name FOREIGN KEY (blueprint_name, hostgroup_name) REFERENCES hostgroup (blueprint_name, name);
  126. ALTER TABLE requestresourcefilter ADD CONSTRAINT FK_reqresfilter_req_id FOREIGN KEY (request_id) REFERENCES request (request_id);
  127. ALTER TABLE requestoperationlevel ADD CONSTRAINT FK_req_op_level_req_id FOREIGN KEY (request_id) REFERENCES request (request_id);
  128. ALTER TABLE viewparameter ADD CONSTRAINT FK_viewparam_view_name FOREIGN KEY (view_name) REFERENCES viewmain(view_name);
  129. ALTER TABLE viewresource ADD CONSTRAINT FK_viewres_view_name FOREIGN KEY (view_name) REFERENCES viewmain(view_name);
  130. ALTER TABLE viewinstance ADD CONSTRAINT FK_viewinst_view_name FOREIGN KEY (view_name) REFERENCES viewmain(view_name);
  131. ALTER TABLE viewinstanceproperty ADD CONSTRAINT FK_viewinstprop_view_name FOREIGN KEY (view_name, view_instance_name) REFERENCES viewinstance(view_name, name);
  132. ALTER TABLE viewinstancedata ADD CONSTRAINT FK_viewinstdata_view_name FOREIGN KEY (view_instance_id, view_name, view_instance_name) REFERENCES viewinstance(view_instance_id, view_name, name);
  133. ALTER TABLE viewentity ADD CONSTRAINT FK_viewentity_view_name FOREIGN KEY (view_name, view_instance_name) REFERENCES viewinstance(view_name, name);
  134. ALTER TABLE adminresource ADD CONSTRAINT FK_resource_resource_type_id FOREIGN KEY (resource_type_id) REFERENCES adminresourcetype(resource_type_id);
  135. ALTER TABLE adminprincipal ADD CONSTRAINT FK_principal_principal_type_id FOREIGN KEY (principal_type_id) REFERENCES adminprincipaltype(principal_type_id);
  136. ALTER TABLE adminpermission ADD CONSTRAINT FK_permission_resource_type_id FOREIGN KEY (resource_type_id) REFERENCES adminresourcetype(resource_type_id);
  137. ALTER TABLE adminprivilege ADD CONSTRAINT FK_privilege_permission_id FOREIGN KEY (permission_id) REFERENCES adminpermission(permission_id);
  138. ALTER TABLE adminprivilege ADD CONSTRAINT FK_privilege_resource_id FOREIGN KEY (resource_id) REFERENCES adminresource(resource_id);
  139. ALTER TABLE viewmain ADD CONSTRAINT FK_view_resource_type_id FOREIGN KEY (resource_type_id) REFERENCES adminresourcetype(resource_type_id);
  140. ALTER TABLE viewinstance ADD CONSTRAINT FK_viewinstance_resource_id FOREIGN KEY (resource_id) REFERENCES adminresource(resource_id);
  141. ALTER TABLE adminprivilege ADD CONSTRAINT FK_privilege_principal_id FOREIGN KEY (principal_id) REFERENCES adminprincipal(principal_id);
  142. ALTER TABLE users ADD CONSTRAINT FK_users_principal_id FOREIGN KEY (principal_id) REFERENCES adminprincipal(principal_id);
  143. ALTER TABLE groups ADD CONSTRAINT FK_groups_principal_id FOREIGN KEY (principal_id) REFERENCES adminprincipal(principal_id);
  144. ALTER TABLE clusters ADD CONSTRAINT FK_clusters_resource_id FOREIGN KEY (resource_id) REFERENCES adminresource(resource_id);
  145. -- Alerting Framework
  146. CREATE TABLE alert_definition (
  147. definition_id BIGINT NOT NULL,
  148. cluster_id BIGINT NOT NULL,
  149. definition_name VARCHAR(255) NOT NULL,
  150. service_name VARCHAR(255) NOT NULL,
  151. component_name VARCHAR(255),
  152. scope VARCHAR(255) DEFAULT 'ANY' NOT NULL,
  153. label VARCHAR(255),
  154. enabled SMALLINT DEFAULT 1 NOT NULL,
  155. schedule_interval INTEGER NOT NULL,
  156. source_type VARCHAR(255) NOT NULL,
  157. alert_source TEXT NOT NULL,
  158. hash VARCHAR(64) NOT NULL,
  159. PRIMARY KEY (definition_id),
  160. FOREIGN KEY (cluster_id) REFERENCES clusters(cluster_id),
  161. CONSTRAINT uni_alert_def_name UNIQUE(cluster_id,definition_name)
  162. );
  163. CREATE TABLE alert_history (
  164. alert_id BIGINT NOT NULL,
  165. cluster_id BIGINT NOT NULL,
  166. alert_definition_id BIGINT NOT NULL,
  167. service_name VARCHAR(255) NOT NULL,
  168. component_name VARCHAR(255),
  169. host_name VARCHAR(255),
  170. alert_instance VARCHAR(255),
  171. alert_timestamp BIGINT NOT NULL,
  172. alert_label VARCHAR(1024),
  173. alert_state VARCHAR(255) NOT NULL,
  174. alert_text TEXT,
  175. PRIMARY KEY (alert_id),
  176. FOREIGN KEY (alert_definition_id) REFERENCES alert_definition(definition_id),
  177. FOREIGN KEY (cluster_id) REFERENCES clusters(cluster_id)
  178. );
  179. CREATE TABLE alert_current (
  180. alert_id BIGINT NOT NULL,
  181. definition_id BIGINT NOT NULL,
  182. history_id BIGINT NOT NULL UNIQUE,
  183. maintenance_state VARCHAR(255),
  184. original_timestamp BIGINT NOT NULL,
  185. latest_timestamp BIGINT NOT NULL,
  186. latest_text TEXT,
  187. PRIMARY KEY (alert_id),
  188. FOREIGN KEY (definition_id) REFERENCES alert_definition(definition_id),
  189. FOREIGN KEY (history_id) REFERENCES alert_history(alert_id)
  190. );
  191. CREATE TABLE alert_group (
  192. group_id BIGINT NOT NULL,
  193. cluster_id BIGINT NOT NULL,
  194. group_name VARCHAR(255) NOT NULL,
  195. is_default SMALLINT NOT NULL DEFAULT 0,
  196. service_name VARCHAR(255),
  197. PRIMARY KEY (group_id),
  198. CONSTRAINT uni_alert_group_name UNIQUE(cluster_id,group_name)
  199. );
  200. CREATE TABLE alert_target (
  201. target_id BIGINT NOT NULL,
  202. target_name VARCHAR(255) NOT NULL UNIQUE,
  203. notification_type VARCHAR(64) NOT NULL,
  204. properties TEXT,
  205. description VARCHAR(1024),
  206. PRIMARY KEY (target_id)
  207. );
  208. CREATE TABLE alert_target_states (
  209. target_id BIGINT NOT NULL,
  210. alert_state VARCHAR(255) NOT NULL,
  211. FOREIGN KEY (target_id) REFERENCES alert_target(target_id)
  212. );
  213. CREATE TABLE alert_group_target (
  214. group_id BIGINT NOT NULL,
  215. target_id BIGINT NOT NULL,
  216. PRIMARY KEY (group_id, target_id),
  217. FOREIGN KEY (group_id) REFERENCES alert_group(group_id),
  218. FOREIGN KEY (target_id) REFERENCES alert_target(target_id)
  219. );
  220. CREATE TABLE alert_grouping (
  221. definition_id BIGINT NOT NULL,
  222. group_id BIGINT NOT NULL,
  223. PRIMARY KEY (group_id, definition_id),
  224. FOREIGN KEY (definition_id) REFERENCES alert_definition(definition_id),
  225. FOREIGN KEY (group_id) REFERENCES alert_group(group_id)
  226. );
  227. CREATE TABLE alert_notice (
  228. notification_id BIGINT NOT NULL,
  229. target_id BIGINT NOT NULL,
  230. history_id BIGINT NOT NULL,
  231. notify_state VARCHAR(255) NOT NULL,
  232. uuid VARCHAR(64) NOT NULL UNIQUE,
  233. PRIMARY KEY (notification_id),
  234. FOREIGN KEY (target_id) REFERENCES alert_target(target_id),
  235. FOREIGN KEY (history_id) REFERENCES alert_history(alert_id)
  236. );
  237. CREATE INDEX idx_alert_history_def_id on alert_history(alert_definition_id);
  238. CREATE INDEX idx_alert_history_service on alert_history(service_name);
  239. CREATE INDEX idx_alert_history_host on alert_history(host_name);
  240. CREATE INDEX idx_alert_history_time on alert_history(alert_timestamp);
  241. CREATE INDEX idx_alert_history_state on alert_history(alert_state);
  242. CREATE INDEX idx_alert_group_name on alert_group(group_name);
  243. CREATE INDEX idx_alert_notice_state on alert_notice(notify_state);
  244. -- upgrade tables
  245. CREATE TABLE upgrade (
  246. upgrade_id BIGINT NOT NULL,
  247. cluster_id BIGINT NOT NULL,
  248. state VARCHAR(255) DEFAULT 'NONE' NOT NULL,
  249. PRIMARY KEY (upgrade_id),
  250. FOREIGN KEY (cluster_id) REFERENCES ambari.clusters(cluster_id)
  251. );
  252. CREATE TABLE upgrade_item (
  253. upgrade_item_id BIGINT NOT NULL,
  254. upgrade_id BIGINT NOT NULL,
  255. state VARCHAR(255) DEFAULT 'NONE' NOT NULL,
  256. hosts TEXT,
  257. tasks TEXT,
  258. item_text VARCHAR(1024),
  259. PRIMARY KEY (upgrade_item_id),
  260. FOREIGN KEY (upgrade_id) REFERENCES upgrade(upgrade_id)
  261. );
  262. ---------inserting some data-----------
  263. BEGIN TRANSACTION
  264. INSERT INTO ambari_sequences (sequence_name, [sequence_value])
  265. SELECT 'cluster_id_seq', 1
  266. UNION ALL
  267. SELECT 'host_role_command_id_seq', 1
  268. UNION ALL
  269. SELECT 'user_id_seq', 2
  270. UNION ALL
  271. SELECT 'group_id_seq', 1
  272. UNION ALL
  273. SELECT 'member_id_seq', 1
  274. UNION ALL
  275. SELECT 'configgroup_id_seq', 1
  276. UNION ALL
  277. SELECT 'requestschedule_id_seq', 1
  278. UNION ALL
  279. SELECT 'resourcefilter_id_seq', 1
  280. UNION ALL
  281. SELECT 'viewentity_id_seq', 0
  282. UNION ALL
  283. SELECT 'operation_level_id_seq', 1
  284. UNION ALL
  285. SELECT 'view_instance_id_seq', 1
  286. UNION ALL
  287. SELECT 'resource_type_id_seq', 4
  288. UNION ALL
  289. SELECT 'resource_id_seq', 2
  290. UNION ALL
  291. SELECT 'principal_type_id_seq', 3
  292. UNION ALL
  293. SELECT 'principal_id_seq', 2
  294. UNION ALL
  295. SELECT 'permission_id_seq', 5
  296. UNION ALL
  297. SELECT 'privilege_id_seq', 1
  298. UNION ALL
  299. SELECT 'config_id_seq', 1
  300. UNION ALL
  301. SELECT 'service_config_id_seq', 1
  302. UNION ALL
  303. SELECT 'alert_definition_id_seq', 0
  304. UNION ALL
  305. SELECT 'alert_group_id_seq', 0
  306. UNION ALL
  307. SELECT 'alert_target_id_seq', 0
  308. UNION ALL
  309. SELECT 'alert_history_id_seq', 0
  310. UNION ALL
  311. SELECT 'alert_notice_id_seq', 0
  312. UNION ALL
  313. SELECT 'alert_current_id_seq', 0
  314. UNION ALL
  315. SELECT 'upgrade_id_seq', 0
  316. UNION ALL
  317. SELECT 'upgrade_item_id_seq', 0;
  318. insert into adminresourcetype (resource_type_id, resource_type_name)
  319. select 1, 'AMBARI'
  320. union all
  321. select 2, 'CLUSTER'
  322. union all
  323. select 3, 'VIEW';
  324. insert into adminresource (resource_id, resource_type_id)
  325. select 1, 1;
  326. insert into adminprincipaltype (principal_type_id, principal_type_name)
  327. select 1, 'USER'
  328. union all
  329. select 2, 'GROUP';
  330. insert into adminprincipal (principal_id, principal_type_id)
  331. select 1, 1;
  332. insert into users(user_id, principal_id, user_name, user_password)
  333. select 1, 1, 'admin','538916f8943ec225d97a9a86a2c6ec0818c1cd400e09e03b660fdaaec4af29ddbb6f2b1033b81b00';
  334. insert into adminpermission(permission_id, permission_name, resource_type_id)
  335. select 1, 'AMBARI.ADMIN', 1
  336. union all
  337. select 2, 'CLUSTER.READ', 2
  338. union all
  339. select 3, 'CLUSTER.OPERATE', 2
  340. union all
  341. select 4, 'VIEW.USE', 3;
  342. insert into adminprivilege (privilege_id, permission_id, resource_id, principal_id)
  343. select 1, 1, 1, 1;
  344. insert into metainfo(metainfo_key, metainfo_value)
  345. select 'version','${ambariVersion}';
  346. COMMIT TRANSACTION
  347. -- Quartz tables
  348. CREATE TABLE qrtz_job_details
  349. (
  350. SCHED_NAME VARCHAR(120) NOT NULL,
  351. JOB_NAME VARCHAR(200) NOT NULL,
  352. JOB_GROUP VARCHAR(200) NOT NULL,
  353. DESCRIPTION VARCHAR(250) NULL,
  354. JOB_CLASS_NAME VARCHAR(250) NOT NULL,
  355. IS_DURABLE BIT NOT NULL,
  356. IS_NONCONCURRENT BIT NOT NULL,
  357. IS_UPDATE_DATA BIT NOT NULL,
  358. REQUESTS_RECOVERY BIT NOT NULL,
  359. JOB_DATA VARBINARY(MAX) NULL,
  360. PRIMARY KEY CLUSTERED (SCHED_NAME,JOB_NAME,JOB_GROUP)
  361. );
  362. CREATE TABLE qrtz_triggers
  363. (
  364. SCHED_NAME VARCHAR(120) NOT NULL,
  365. TRIGGER_NAME VARCHAR(200) NOT NULL,
  366. TRIGGER_GROUP VARCHAR(200) NOT NULL,
  367. JOB_NAME VARCHAR(200) NOT NULL,
  368. JOB_GROUP VARCHAR(200) NOT NULL,
  369. DESCRIPTION VARCHAR(250) NULL,
  370. NEXT_FIRE_TIME BIGINT NULL,
  371. PREV_FIRE_TIME BIGINT NULL,
  372. PRIORITY INTEGER NULL,
  373. TRIGGER_STATE VARCHAR(16) NOT NULL,
  374. TRIGGER_TYPE VARCHAR(8) NOT NULL,
  375. START_TIME BIGINT NOT NULL,
  376. END_TIME BIGINT NULL,
  377. CALENDAR_NAME VARCHAR(200) NULL,
  378. MISFIRE_INSTR SMALLINT NULL,
  379. JOB_DATA VARBINARY(MAX) NULL,
  380. PRIMARY KEY CLUSTERED (SCHED_NAME,TRIGGER_NAME,TRIGGER_GROUP),
  381. FOREIGN KEY (SCHED_NAME,JOB_NAME,JOB_GROUP)
  382. REFERENCES QRTZ_JOB_DETAILS(SCHED_NAME,JOB_NAME,JOB_GROUP)
  383. );
  384. CREATE TABLE qrtz_simple_triggers
  385. (
  386. SCHED_NAME VARCHAR(120) NOT NULL,
  387. TRIGGER_NAME VARCHAR(200) NOT NULL,
  388. TRIGGER_GROUP VARCHAR(200) NOT NULL,
  389. REPEAT_COUNT BIGINT NOT NULL,
  390. REPEAT_INTERVAL BIGINT NOT NULL,
  391. TIMES_TRIGGERED BIGINT NOT NULL,
  392. PRIMARY KEY CLUSTERED (SCHED_NAME,TRIGGER_NAME,TRIGGER_GROUP),
  393. FOREIGN KEY (SCHED_NAME,TRIGGER_NAME,TRIGGER_GROUP)
  394. REFERENCES QRTZ_TRIGGERS(SCHED_NAME,TRIGGER_NAME,TRIGGER_GROUP)
  395. );
  396. CREATE TABLE qrtz_cron_triggers
  397. (
  398. SCHED_NAME VARCHAR(120) NOT NULL,
  399. TRIGGER_NAME VARCHAR(200) NOT NULL,
  400. TRIGGER_GROUP VARCHAR(200) NOT NULL,
  401. CRON_EXPRESSION VARCHAR(120) NOT NULL,
  402. TIME_ZONE_ID VARCHAR(80),
  403. PRIMARY KEY CLUSTERED (SCHED_NAME,TRIGGER_NAME,TRIGGER_GROUP),
  404. FOREIGN KEY (SCHED_NAME,TRIGGER_NAME,TRIGGER_GROUP)
  405. REFERENCES QRTZ_TRIGGERS(SCHED_NAME,TRIGGER_NAME,TRIGGER_GROUP)
  406. );
  407. CREATE TABLE qrtz_simprop_triggers
  408. (
  409. SCHED_NAME VARCHAR(120) NOT NULL,
  410. TRIGGER_NAME VARCHAR(200) NOT NULL,
  411. TRIGGER_GROUP VARCHAR(200) NOT NULL,
  412. STR_PROP_1 VARCHAR(512) NULL,
  413. STR_PROP_2 VARCHAR(512) NULL,
  414. STR_PROP_3 VARCHAR(512) NULL,
  415. INT_PROP_1 INT NULL,
  416. INT_PROP_2 INT NULL,
  417. LONG_PROP_1 BIGINT NULL,
  418. LONG_PROP_2 BIGINT NULL,
  419. DEC_PROP_1 NUMERIC(13,4) NULL,
  420. DEC_PROP_2 NUMERIC(13,4) NULL,
  421. BOOL_PROP_1 BIT NULL,
  422. BOOL_PROP_2 BIT NULL,
  423. PRIMARY KEY CLUSTERED (SCHED_NAME,TRIGGER_NAME,TRIGGER_GROUP),
  424. FOREIGN KEY (SCHED_NAME,TRIGGER_NAME,TRIGGER_GROUP)
  425. REFERENCES QRTZ_TRIGGERS(SCHED_NAME,TRIGGER_NAME,TRIGGER_GROUP)
  426. );
  427. CREATE TABLE qrtz_blob_triggers
  428. (
  429. SCHED_NAME VARCHAR(120) NOT NULL,
  430. TRIGGER_NAME VARCHAR(200) NOT NULL,
  431. TRIGGER_GROUP VARCHAR(200) NOT NULL,
  432. BLOB_DATA VARBINARY(MAX) NULL,
  433. PRIMARY KEY CLUSTERED (SCHED_NAME,TRIGGER_NAME,TRIGGER_GROUP),
  434. FOREIGN KEY (SCHED_NAME,TRIGGER_NAME,TRIGGER_GROUP)
  435. REFERENCES QRTZ_TRIGGERS(SCHED_NAME,TRIGGER_NAME,TRIGGER_GROUP)
  436. );
  437. CREATE TABLE qrtz_calendars
  438. (
  439. SCHED_NAME VARCHAR(120) NOT NULL,
  440. CALENDAR_NAME VARCHAR(200) NOT NULL,
  441. CALENDAR VARBINARY(MAX) NOT NULL,
  442. PRIMARY KEY CLUSTERED (SCHED_NAME,CALENDAR_NAME)
  443. );
  444. CREATE TABLE qrtz_paused_trigger_grps
  445. (
  446. SCHED_NAME VARCHAR(120) NOT NULL,
  447. TRIGGER_GROUP VARCHAR(200) NOT NULL,
  448. PRIMARY KEY CLUSTERED (SCHED_NAME,TRIGGER_GROUP)
  449. );
  450. CREATE TABLE qrtz_fired_triggers
  451. (
  452. SCHED_NAME VARCHAR(120) NOT NULL,
  453. ENTRY_ID VARCHAR(95) NOT NULL,
  454. TRIGGER_NAME VARCHAR(200) NOT NULL,
  455. TRIGGER_GROUP VARCHAR(200) NOT NULL,
  456. INSTANCE_NAME VARCHAR(200) NOT NULL,
  457. FIRED_TIME BIGINT NOT NULL,
  458. SCHED_TIME BIGINT NOT NULL,
  459. PRIORITY INTEGER NOT NULL,
  460. STATE VARCHAR(16) NOT NULL,
  461. JOB_NAME VARCHAR(200) NULL,
  462. JOB_GROUP VARCHAR(200) NULL,
  463. IS_NONCONCURRENT BIT NULL,
  464. REQUESTS_RECOVERY BIT NULL,
  465. PRIMARY KEY CLUSTERED (SCHED_NAME,ENTRY_ID)
  466. );
  467. CREATE TABLE qrtz_scheduler_state
  468. (
  469. SCHED_NAME VARCHAR(120) NOT NULL,
  470. INSTANCE_NAME VARCHAR(200) NOT NULL,
  471. LAST_CHECKIN_TIME BIGINT NOT NULL,
  472. CHECKIN_INTERVAL BIGINT NOT NULL,
  473. PRIMARY KEY CLUSTERED (SCHED_NAME,INSTANCE_NAME)
  474. );
  475. CREATE TABLE qrtz_locks
  476. (
  477. SCHED_NAME VARCHAR(120) NOT NULL,
  478. LOCK_NAME VARCHAR(40) NOT NULL,
  479. PRIMARY KEY CLUSTERED (SCHED_NAME,LOCK_NAME)
  480. );
  481. create index idx_qrtz_j_req_recovery on qrtz_job_details(SCHED_NAME,REQUESTS_RECOVERY);
  482. create index idx_qrtz_j_grp on qrtz_job_details(SCHED_NAME,JOB_GROUP);
  483. create index idx_qrtz_t_j on qrtz_triggers(SCHED_NAME,JOB_NAME,JOB_GROUP);
  484. create index idx_qrtz_t_jg on qrtz_triggers(SCHED_NAME,JOB_GROUP);
  485. create index idx_qrtz_t_c on qrtz_triggers(SCHED_NAME,CALENDAR_NAME);
  486. create index idx_qrtz_t_g on qrtz_triggers(SCHED_NAME,TRIGGER_GROUP);
  487. create index idx_qrtz_t_state on qrtz_triggers(SCHED_NAME,TRIGGER_STATE);
  488. create index idx_qrtz_t_n_state on qrtz_triggers(SCHED_NAME,TRIGGER_NAME,TRIGGER_GROUP,TRIGGER_STATE);
  489. create index idx_qrtz_t_n_g_state on qrtz_triggers(SCHED_NAME,TRIGGER_GROUP,TRIGGER_STATE);
  490. create index idx_qrtz_t_next_fire_time on qrtz_triggers(SCHED_NAME,NEXT_FIRE_TIME);
  491. create index idx_qrtz_t_nft_st on qrtz_triggers(SCHED_NAME,TRIGGER_STATE,NEXT_FIRE_TIME);
  492. create index idx_qrtz_t_nft_misfire on qrtz_triggers(SCHED_NAME,MISFIRE_INSTR,NEXT_FIRE_TIME);
  493. create index idx_qrtz_t_nft_st_misfire on qrtz_triggers(SCHED_NAME,MISFIRE_INSTR,NEXT_FIRE_TIME,TRIGGER_STATE);
  494. create index idx_qrtz_t_nft_st_misfire_grp on qrtz_triggers(SCHED_NAME,MISFIRE_INSTR,NEXT_FIRE_TIME,TRIGGER_GROUP,TRIGGER_STATE);
  495. create index idx_qrtz_ft_trig_inst_name on qrtz_fired_triggers(SCHED_NAME,INSTANCE_NAME);
  496. create index idx_qrtz_ft_inst_job_req_rcvry on qrtz_fired_triggers(SCHED_NAME,INSTANCE_NAME,REQUESTS_RECOVERY);
  497. create index idx_qrtz_ft_j_g on qrtz_fired_triggers(SCHED_NAME,JOB_NAME,JOB_GROUP);
  498. create index idx_qrtz_ft_jg on qrtz_fired_triggers(SCHED_NAME,JOB_GROUP);
  499. create index idx_qrtz_ft_t_g on qrtz_fired_triggers(SCHED_NAME,TRIGGER_NAME,TRIGGER_GROUP);
  500. create index idx_qrtz_ft_tg on qrtz_fired_triggers(SCHED_NAME,TRIGGER_GROUP);
  501. -- ambari log4j DDL
  502. CREATE TABLE workflow (
  503. workflowId varchar(255) PRIMARY KEY CLUSTERED,
  504. workflowName varchar(255),
  505. parentWorkflowId varchar(255),
  506. workflowContext TEXT, userName varchar(255),
  507. startTime BIGINT, lastUpdateTime BIGINT,
  508. numJobsTotal INTEGER, numJobsCompleted INTEGER,
  509. inputBytes BIGINT, outputBytes BIGINT,
  510. duration BIGINT,
  511. FOREIGN KEY (parentWorkflowId) REFERENCES workflow (workflowId)
  512. );
  513. CREATE TABLE job (
  514. jobId varchar(255) NOT NULL,
  515. workflowId varchar(255) NOT NULL,
  516. jobName varchar(255), workflowEntityName varchar(255),
  517. userName varchar(255), queue varchar(255), acls varchar(2000), confPath varchar(260),
  518. submitTime BIGINT, launchTime BIGINT, finishTime BIGINT,
  519. maps INTEGER, reduces INTEGER, status varchar(255), priority varchar(255),
  520. finishedMaps INTEGER, finishedReduces INTEGER,
  521. failedMaps INTEGER, failedReduces INTEGER,
  522. mapsRuntime BIGINT, reducesRuntime BIGINT,
  523. mapCounters TEXT, reduceCounters TEXT, jobCounters TEXT,
  524. inputBytes BIGINT, outputBytes BIGINT,
  525. PRIMARY KEY CLUSTERED (jobId),
  526. FOREIGN KEY (workflowId) REFERENCES workflow (workflowId)
  527. );
  528. CREATE TABLE task (
  529. taskId varchar(255) NOT NULL,
  530. jobId varchar(255) NOT NULL,
  531. taskType varchar(255), splits varchar(2000),
  532. startTime BIGINT, finishTime BIGINT, status TEXT, error TEXT, counters TEXT,
  533. failedAttempt TEXT,
  534. PRIMARY KEY CLUSTERED (taskId),
  535. FOREIGN KEY (jobId) REFERENCES job (jobId)
  536. );
  537. CREATE TABLE taskAttempt (
  538. taskAttemptId varchar(255) NOT NULL,
  539. taskId varchar(255) NOT NULL,
  540. jobId varchar(255) NOT NULL,
  541. taskType varchar(255), taskTracker varchar(255),
  542. startTime BIGINT, finishTime BIGINT,
  543. mapFinishTime BIGINT, shuffleFinishTime BIGINT, sortFinishTime BIGINT,
  544. locality TEXT, avataar TEXT,
  545. status TEXT, error TEXT, counters TEXT,
  546. inputBytes BIGINT, outputBytes BIGINT,
  547. PRIMARY KEY CLUSTERED (taskAttemptId),
  548. FOREIGN KEY (jobId) REFERENCES job (jobId),
  549. FOREIGN KEY (taskId) REFERENCES task (taskId)
  550. );
  551. CREATE TABLE hdfsEvent (
  552. timestamp BIGINT,
  553. userName varchar(255),
  554. clientIP varchar(255),
  555. operation varchar(255),
  556. srcPath varchar(260),
  557. dstPath varchar(260),
  558. permissions TEXT
  559. );
  560. CREATE TABLE mapreduceEvent (
  561. timestamp BIGINT,
  562. userName varchar(255),
  563. clientIP varchar(255),
  564. operation varchar(255),
  565. target varchar(255),
  566. result TEXT,
  567. description TEXT,
  568. permissions TEXT
  569. );
  570. CREATE TABLE clusterEvent (
  571. timestamp BIGINT,
  572. service varchar(255), status TEXT,
  573. error TEXT, data TEXT,
  574. host TEXT, rack TEXT
  575. );
  576. GO
  577. IF OBJECT_ID ('trigger_workflow_delete','TR') IS NOT NULL
  578. DROP TRIGGER trigger_workflow_delete;
  579. GO
  580. CREATE TRIGGER trigger_workflow_delete
  581. ON workflow
  582. INSTEAD OF DELETE
  583. AS
  584. BEGIN
  585. declare @cteTmp table
  586. (
  587. rowid int identity,
  588. workflowId varchar(255)
  589. );
  590. declare @cteTmpRev table
  591. (
  592. rowid int identity,
  593. workflowId varchar(255)
  594. );
  595. --the trigger does not get called recursively, so we need to store the child node ids in a temp table
  596. with cte as
  597. (
  598. select wr.workflowId workflowId
  599. from workflow wr inner join deleted d ON wr.workflowId = d.workflowId
  600. union all
  601. select w.workflowId
  602. from cte
  603. inner join workflow w on cte.workflowId = w.parentWorkflowId
  604. )
  605. insert into @cteTmp
  606. select workflowId from cte;
  607. --order by is invalid in subqueries and common table expression queries, do whatever we can
  608. -- watch out for scalability issues due to data duplication
  609. insert into @cteTmpRev
  610. select workflowId from @cteTmp
  611. order by rowid desc;
  612. --delete from the referred tables
  613. delete from job
  614. from job j inner join @cteTmpRev r on j.workflowId = r.workflowId;
  615. --finally delete from the master table
  616. delete from workflow
  617. from workflow w inner join @cteTmpRev r on w.workflowId = r.workflowId
  618. END
  619. GO
  620. IF OBJECT_ID ('trigger_job_delete','TR') IS NOT NULL
  621. DROP TRIGGER trigger_job_delete;
  622. GO
  623. CREATE TRIGGER trigger_job_delete
  624. ON job
  625. INSTEAD OF DELETE
  626. AS
  627. BEGIN
  628. --delete from referred tables
  629. delete from task
  630. from task t inner join deleted d on t.jobId = d.jobId
  631. delete from job
  632. from job j inner join deleted d on j.jobId = d.jobId
  633. END
  634. GO
  635. IF OBJECT_ID ('trigger_task_delete','TR') IS NOT NULL
  636. DROP TRIGGER trigger_task_delete;
  637. GO
  638. CREATE TRIGGER trigger_task_delete
  639. ON task
  640. INSTEAD OF DELETE
  641. AS
  642. BEGIN
  643. --delete from referred tables
  644. delete from taskAttempt
  645. from taskAttempt ta inner join task t on ta.taskId = t.taskId
  646. inner join deleted d on t.jobId = d.jobId
  647. delete from task
  648. from task t inner join deleted d on t.taskId = d.taskId
  649. END
  650. GO