upgrade-00-000-to-02-000.sql 12 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296297298299300301302303304305306307308309310311312313314315316317318319320321322323324325326327328329330331332333334335336337338339340341342343344345346347348349350351352353354355356357358359360361362363364365366367368369370371372373374375376377378379380381382383384385386387388389390391392393394395396
  1. -- Licensed Materials - Property of IBM
  2. -- BI and PM: Mobile
  3. -- (C) Copyright IBM Corp. 2007, 2012
  4. -- US Government Users Restricted Rights - Use, duplication or disclosure restricted by GSA ADP Schedule Contract with IBM Corp.
  5. --
  6. -- Mobile database table creation scripts for MS SQL 2000.
  7. -- MOB_RESOURCES
  8. DECLARE
  9. TABLE_EXISTS_EXCEPTION EXCEPTION;
  10. PRAGMA EXCEPTION_INIT (TABLE_EXISTS_EXCEPTION, -955);
  11. BEGIN
  12. EXECUTE IMMEDIATE 'CREATE TABLE MOB_RESOURCES (
  13. RESOURCE_ID int PRIMARY KEY NOT NULL,
  14. LABEL varchar (100) NULL,
  15. IDENTIFIER varchar (200) NULL,
  16. CM_PATH varchar (1000) NULL,
  17. SOURCE_PATH varchar (1000) NULL,
  18. DESCRIPTION varchar (500) NULL,
  19. RESOURCE_TYPE int DEFAULT 0 NOT NULL
  20. )';
  21. EXECUTE IMMEDIATE 'CREATE INDEX IDX_MOB_REP_ID ON MOB_RESOURCES(IDENTIFIER)';
  22. EXCEPTION
  23. WHEN TABLE_EXISTS_EXCEPTION THEN
  24. NULL;
  25. END;
  26. /
  27. DECLARE
  28. SEQUENCE_EXISTS_EXCEPTION EXCEPTION;
  29. PRAGMA EXCEPTION_INIT (SEQUENCE_EXISTS_EXCEPTION, -955);
  30. BEGIN
  31. EXECUTE IMMEDIATE 'CREATE SEQUENCE SEQ_MOB_RESOURCES START WITH 1 INCREMENT BY 1 NOMAXVALUE';
  32. EXCEPTION
  33. WHEN SEQUENCE_EXISTS_EXCEPTION THEN
  34. NULL;
  35. END;
  36. /
  37. CREATE OR REPLACE TRIGGER "TRIGGER_MOB_RESOURCES" BEFORE INSERT ON "MOB_RESOURCES" FOR EACH ROW
  38. BEGIN
  39. SELECT SEQ_MOB_RESOURCES.nextval INTO :new.RESOURCE_ID FROM DUAL;
  40. END;
  41. /
  42. -- MOB_RENDERS
  43. DECLARE
  44. TABLE_EXISTS_EXCEPTION EXCEPTION;
  45. PRAGMA EXCEPTION_INIT (TABLE_EXISTS_EXCEPTION, -955);
  46. BEGIN
  47. EXECUTE IMMEDIATE 'CREATE TABLE MOB_RENDERS (
  48. RENDER_ID int PRIMARY KEY NOT NULL, -- identity
  49. RENDER_TIME timestamp NOT NULL,
  50. RENDER_SIZE int NOT NULL,
  51. STATUS_CODE int NOT NULL,
  52. SOURCE_CODE smallint NULL,
  53. DRILL_PARAMS varchar (1000) NULL,
  54. RESOURCE_ID int NOT NULL,
  55. CONSTRAINT FK_MOB_R_RSID FOREIGN KEY(RESOURCE_ID) REFERENCES MOB_RESOURCES(RESOURCE_ID)
  56. )';
  57. EXCEPTION
  58. WHEN TABLE_EXISTS_EXCEPTION THEN
  59. NULL;
  60. END;
  61. /
  62. DECLARE
  63. SEQUENCE_EXISTS_EXCEPTION EXCEPTION;
  64. PRAGMA EXCEPTION_INIT (SEQUENCE_EXISTS_EXCEPTION, -955);
  65. BEGIN
  66. EXECUTE IMMEDIATE 'CREATE SEQUENCE SEQ_MOB_RENDERS START WITH 1 INCREMENT BY 1 NOMAXVALUE';
  67. EXCEPTION
  68. WHEN SEQUENCE_EXISTS_EXCEPTION THEN
  69. NULL;
  70. END;
  71. /
  72. CREATE OR REPLACE TRIGGER "TRIGGER_MOB_RENDERS" BEFORE INSERT ON "MOB_RENDERS" FOR EACH ROW
  73. BEGIN
  74. SELECT SEQ_MOB_RENDERS.nextval INTO :new.RENDER_ID FROM DUAL;
  75. END;
  76. /
  77. -- MOB_USERS
  78. DECLARE
  79. TABLE_EXISTS_EXCEPTION EXCEPTION;
  80. PRAGMA EXCEPTION_INIT (TABLE_EXISTS_EXCEPTION, -955);
  81. BEGIN
  82. EXECUTE IMMEDIATE 'CREATE TABLE MOB_USERS (
  83. USER_ID int PRIMARY KEY NOT NULL,
  84. DEVICE_ID varchar (100) NULL,
  85. DEVICE_PROFILE varchar (200) NULL,
  86. CREDENTIAL_PATH varchar (200) NULL,
  87. CAM_ID varchar (100) NULL,
  88. KEY_TYPE varchar (20) NULL,
  89. KEY_BYTES blob NULL,
  90. SYNC_METHOD varchar (20) NULL,
  91. LAST_LOGIN timestamp NULL
  92. )';
  93. EXECUTE IMMEDIATE 'CREATE INDEX IDX_CAM_ID ON MOB_USERS(CAM_ID)';
  94. EXCEPTION
  95. WHEN TABLE_EXISTS_EXCEPTION THEN
  96. NULL;
  97. END;
  98. /
  99. DECLARE
  100. SEQUENCE_EXISTS_EXCEPTION EXCEPTION;
  101. PRAGMA EXCEPTION_INIT (SEQUENCE_EXISTS_EXCEPTION, -955);
  102. BEGIN
  103. EXECUTE IMMEDIATE 'CREATE SEQUENCE SEQ_MOB_USERS START WITH 1 INCREMENT BY 1 NOMAXVALUE';
  104. EXCEPTION
  105. WHEN SEQUENCE_EXISTS_EXCEPTION THEN
  106. NULL;
  107. END;
  108. /
  109. CREATE OR REPLACE TRIGGER "TRIGGER_MOB_USERS" BEFORE INSERT ON "MOB_USERS" FOR EACH ROW
  110. BEGIN
  111. SELECT SEQ_MOB_USERS.nextval INTO :new.USER_ID FROM DUAL;
  112. END;
  113. /
  114. -- MOB_USER_RENDER
  115. DECLARE
  116. TABLE_EXISTS_EXCEPTION EXCEPTION;
  117. PRAGMA EXCEPTION_INIT (TABLE_EXISTS_EXCEPTION, -955);
  118. BEGIN
  119. EXECUTE IMMEDIATE 'CREATE TABLE MOB_USER_RENDER (
  120. USER_ID int NOT NULL,
  121. RENDER_ID int NOT NULL,
  122. NAME varchar (100) NULL,
  123. LAST_VIEWED timestamp NULL,
  124. CONSTRAINT FK_MOB_UR_UID FOREIGN KEY(USER_ID) REFERENCES MOB_USERS(USER_ID) ON DELETE CASCADE,
  125. CONSTRAINT FK_MOB_UR_RID FOREIGN KEY(RENDER_ID) REFERENCES MOB_RENDERS(RENDER_ID) ON DELETE CASCADE,
  126. CONSTRAINT PK_MOB_USERRNDR PRIMARY KEY(USER_ID, RENDER_ID)
  127. )';
  128. EXCEPTION
  129. WHEN TABLE_EXISTS_EXCEPTION THEN
  130. NULL;
  131. END;
  132. /
  133. -- MOB_USER_RESOURCE
  134. DECLARE
  135. TABLE_EXISTS_EXCEPTION EXCEPTION;
  136. PRAGMA EXCEPTION_INIT (TABLE_EXISTS_EXCEPTION, -955);
  137. BEGIN
  138. EXECUTE IMMEDIATE 'CREATE TABLE MOB_USER_RESOURCE (
  139. USER_ID int NOT NULL,
  140. RESOURCE_ID int NOT NULL,
  141. USER_RESOURCE_TYPE int DEFAULT 0 NOT NULL,
  142. CONSTRAINT FK_MOB_URS_UID FOREIGN KEY(USER_ID) REFERENCES MOB_USERS(USER_ID) ON DELETE CASCADE,
  143. CONSTRAINT FK_MOB_URS_RSID FOREIGN KEY(RESOURCE_ID) REFERENCES MOB_RESOURCES(RESOURCE_ID) ON DELETE CASCADE,
  144. CONSTRAINT PK_MOB_USERRSRC PRIMARY KEY(USER_ID, RESOURCE_ID)
  145. )';
  146. EXCEPTION
  147. WHEN TABLE_EXISTS_EXCEPTION THEN
  148. NULL;
  149. END;
  150. /
  151. -- MOB_USER_RESOURCE_TYPES
  152. DECLARE
  153. TABLE_EXISTS_EXCEPTION EXCEPTION;
  154. PRAGMA EXCEPTION_INIT (TABLE_EXISTS_EXCEPTION, -955);
  155. BEGIN
  156. EXECUTE IMMEDIATE 'CREATE TABLE MOB_USER_RESOURCE_TYPES (
  157. TYPE smallint NOT NULL,
  158. DESCRIPTION varchar (100) NULL
  159. )';
  160. EXECUTE IMMEDIATE 'INSERT INTO MOB_USER_RESOURCE_TYPES VALUES (0, ''DASHBOARD'')';
  161. EXECUTE IMMEDIATE 'INSERT INTO MOB_USER_RESOURCE_TYPES VALUES (1, ''FAVORITE'')';
  162. EXCEPTION
  163. WHEN TABLE_EXISTS_EXCEPTION THEN
  164. NULL;
  165. END;
  166. /
  167. -- MOB_BLOBS
  168. DECLARE
  169. TABLE_EXISTS_EXCEPTION EXCEPTION;
  170. PRAGMA EXCEPTION_INIT (TABLE_EXISTS_EXCEPTION, -955);
  171. BEGIN
  172. EXECUTE IMMEDIATE 'CREATE TABLE MOB_BLOBS (
  173. BLOB_ID int NOT NULL,
  174. RENDER_ID int NULL,
  175. RESOURCE_ID int NULL,
  176. USER_ID int NULL,
  177. SEQUENCE int NOT NULL,
  178. BLOB_VALUE blob NOT NULL,
  179. FORMAT smallint NULL,
  180. OBJECT_INDEX int NULL,
  181. PAGE_INDEX int NULL,
  182. CONSTRAINT FK_MOB_BLOBS_RID FOREIGN KEY(RENDER_ID) REFERENCES MOB_RENDERS(RENDER_ID) ON DELETE CASCADE,
  183. CONSTRAINT FK_MOB_BLOBS_RSID FOREIGN KEY(RESOURCE_ID) REFERENCES MOB_RESOURCES(RESOURCE_ID) ON DELETE CASCADE,
  184. CONSTRAINT FK_MOB_BLOBS_UID FOREIGN KEY(USER_ID) REFERENCES MOB_USERS(USER_ID) ON DELETE CASCADE
  185. )';
  186. EXECUTE IMMEDIATE 'CREATE INDEX IDX_MOB_BLOBS ON MOB_BLOBS(BLOB_ID, SEQUENCE)';
  187. EXCEPTION
  188. WHEN TABLE_EXISTS_EXCEPTION THEN
  189. NULL;
  190. END;
  191. /
  192. -- MOB_BLOB_FORMATS
  193. DECLARE
  194. TABLE_EXISTS_EXCEPTION EXCEPTION;
  195. PRAGMA EXCEPTION_INIT (TABLE_EXISTS_EXCEPTION, -955);
  196. BEGIN
  197. EXECUTE IMMEDIATE 'CREATE TABLE MOB_BLOB_FORMATS (
  198. FORMAT smallint NOT NULL,
  199. DESCRIPTION varchar (100) NULL
  200. )';
  201. EXECUTE IMMEDIATE 'INSERT INTO MOB_BLOB_FORMATS VALUES (0, ''USER COOKIE'')';
  202. EXECUTE IMMEDIATE 'INSERT INTO MOB_BLOB_FORMATS VALUES (1, ''REPORT INFO'')';
  203. EXECUTE IMMEDIATE 'INSERT INTO MOB_BLOB_FORMATS VALUES (2, ''REPORT OUTPUT'')';
  204. EXECUTE IMMEDIATE 'INSERT INTO MOB_BLOB_FORMATS VALUES (3, ''DB'')';
  205. EXECUTE IMMEDIATE 'INSERT INTO MOB_BLOB_FORMATS VALUES (4, ''PAGE HTML'')';
  206. EXECUTE IMMEDIATE 'INSERT INTO MOB_BLOB_FORMATS VALUES (5, ''IMAGE'')';
  207. EXECUTE IMMEDIATE 'INSERT INTO MOB_BLOB_FORMATS VALUES (6, ''RENDER THUMBNAIL SMALL'')';
  208. EXECUTE IMMEDIATE 'INSERT INTO MOB_BLOB_FORMATS VALUES (7, ''RENDER THUMBNAIL LARGE'')';
  209. EXECUTE IMMEDIATE 'INSERT INTO MOB_BLOB_FORMATS VALUES (8, ''iOS THUMBNAIL SMALL'')';
  210. EXECUTE IMMEDIATE 'INSERT INTO MOB_BLOB_FORMATS VALUES (9, ''iOS THUMBNAIL LARGE'')';
  211. EXECUTE IMMEDIATE 'INSERT INTO MOB_BLOB_FORMATS VALUES (10, ''SVG'')';
  212. EXECUTE IMMEDIATE 'INSERT INTO MOB_BLOB_FORMATS VALUES (11, ''TABLE HTML'')';
  213. EXECUTE IMMEDIATE 'INSERT INTO MOB_BLOB_FORMATS VALUES (12, ''ATTCH IMAGE'')';
  214. EXECUTE IMMEDIATE 'INSERT INTO MOB_BLOB_FORMATS VALUES (13, ''CONVERSATION STATE'')';
  215. EXECUTE IMMEDIATE 'INSERT INTO MOB_BLOB_FORMATS VALUES (14, ''DASHBOARD'')';
  216. EXECUTE IMMEDIATE 'INSERT INTO MOB_BLOB_FORMATS VALUES (15, ''BUX CONVERSATION STATE'')';
  217. EXCEPTION
  218. WHEN TABLE_EXISTS_EXCEPTION THEN
  219. NULL;
  220. END;
  221. /
  222. -- MOB_STATUS_CODES
  223. DECLARE
  224. TABLE_EXISTS_EXCEPTION EXCEPTION;
  225. PRAGMA EXCEPTION_INIT (TABLE_EXISTS_EXCEPTION, -955);
  226. BEGIN
  227. EXECUTE IMMEDIATE 'CREATE TABLE MOB_STATUS_CODES (
  228. STATUS_CODE smallint NOT NULL,
  229. DESCRIPTION varchar (100) NULL
  230. )';
  231. EXECUTE IMMEDIATE 'CREATE INDEX PK_MOB_STATUS_CODES ON MOB_STATUS_CODES(STATUS_CODE)';
  232. EXECUTE IMMEDIATE 'INSERT INTO MOB_STATUS_CODES VALUES (1, ''IN PROGRESS'')';
  233. EXECUTE IMMEDIATE 'INSERT INTO MOB_STATUS_CODES VALUES (2, ''COMPLETED'')';
  234. EXECUTE IMMEDIATE 'INSERT INTO MOB_STATUS_CODES VALUES (3, ''PENDING'')';
  235. EXECUTE IMMEDIATE 'INSERT INTO MOB_STATUS_CODES VALUES (9, ''CANCELLED'')';
  236. EXECUTE IMMEDIATE 'INSERT INTO MOB_STATUS_CODES VALUES (99, ''ERROR'')';
  237. EXCEPTION
  238. WHEN TABLE_EXISTS_EXCEPTION THEN
  239. NULL;
  240. END;
  241. /
  242. -- MOB_SOURCE_CODES
  243. DECLARE
  244. TABLE_EXISTS_EXCEPTION EXCEPTION;
  245. PRAGMA EXCEPTION_INIT (TABLE_EXISTS_EXCEPTION, -955);
  246. BEGIN
  247. EXECUTE IMMEDIATE 'CREATE TABLE MOB_SOURCE_CODES (
  248. SOURCE_CODE smallint NOT NULL,
  249. DESCRIPTION varchar (100) NULL
  250. )';
  251. EXECUTE IMMEDIATE 'CREATE INDEX PK_MOB_SOURCE_CODES ON MOB_SOURCE_CODES(SOURCE_CODE)';
  252. EXECUTE IMMEDIATE 'INSERT INTO MOB_SOURCE_CODES VALUES (0, ''AD-HOC'')';
  253. EXECUTE IMMEDIATE 'INSERT INTO MOB_SOURCE_CODES VALUES (1, ''SCHEDULED/RUN-WITH-OPTIONS'')';
  254. EXECUTE IMMEDIATE 'INSERT INTO MOB_SOURCE_CODES VALUES (2, ''DRILL-THROUGH'')';
  255. EXECUTE IMMEDIATE 'INSERT INTO MOB_SOURCE_CODES VALUES (3, ''DRILL-UP/DOWN'')';
  256. EXCEPTION
  257. WHEN TABLE_EXISTS_EXCEPTION THEN
  258. NULL;
  259. END;
  260. /
  261. -- MOB_TEMPSTORAGE
  262. DECLARE
  263. TABLE_EXISTS_EXCEPTION EXCEPTION;
  264. PRAGMA EXCEPTION_INIT (TABLE_EXISTS_EXCEPTION, -955);
  265. BEGIN
  266. EXECUTE IMMEDIATE 'CREATE TABLE MOB_TEMPSTORAGE (
  267. TS_ID int PRIMARY KEY NOT NULL,
  268. PATH varchar (500) NULL,
  269. CREATED timestamp NOT NULL,
  270. MODIFIED timestamp NOT NULL
  271. )';
  272. EXECUTE IMMEDIATE 'CREATE INDEX IDX_MOB_MODIFIED ON MOB_TEMPSTORAGE(MODIFIED)';
  273. EXECUTE IMMEDIATE 'CREATE INDEX IDX_MOB_CREATED ON MOB_TEMPSTORAGE(CREATED)';
  274. EXECUTE IMMEDIATE 'CREATE INDEX IDX_MOB_TMPPATH ON MOB_TEMPSTORAGE(PATH)';
  275. EXECUTE IMMEDIATE 'CREATE SEQUENCE SEQ_MOB_TEMPSTORAGE START WITH 1 INCREMENT BY 1 NOMAXVALUE';
  276. EXCEPTION
  277. WHEN TABLE_EXISTS_EXCEPTION THEN
  278. NULL;
  279. END;
  280. /
  281. CREATE OR REPLACE TRIGGER "TRIGGER_MOB_TEMPSTORAGE"
  282. BEFORE INSERT
  283. ON "MOB_TEMPSTORAGE"
  284. FOR EACH ROW
  285. BEGIN
  286. SELECT SEQ_MOB_TEMPSTORAGE.NEXTVAL
  287. INTO :NEW.TS_ID
  288. FROM DUAL;
  289. END;
  290. /
  291. -- MOB_TEMPSTOREBLOBS
  292. DECLARE
  293. TABLE_EXISTS_EXCEPTION EXCEPTION;
  294. PRAGMA EXCEPTION_INIT (TABLE_EXISTS_EXCEPTION, -955);
  295. BEGIN
  296. EXECUTE IMMEDIATE 'CREATE TABLE MOB_TEMPSTOREBLOBS (
  297. TS_ID int NOT NULL,
  298. SEQUENCE int NOT NULL,
  299. BLOB_VALUE blob NOT NULL,
  300. CONSTRAINT FK_MOB_TSB_TSID FOREIGN KEY(TS_ID) REFERENCES MOB_TEMPSTORAGE(TS_ID) ON DELETE CASCADE
  301. )';
  302. EXECUTE IMMEDIATE 'CREATE INDEX IDX_MOB_TSBLOBS2 ON MOB_TEMPSTOREBLOBS(TS_ID, SEQUENCE)';
  303. EXCEPTION
  304. WHEN TABLE_EXISTS_EXCEPTION THEN
  305. NULL;
  306. END;
  307. /
  308. -- MOB_HISTORY
  309. DECLARE
  310. TABLE_EXISTS_EXCEPTION EXCEPTION;
  311. PRAGMA EXCEPTION_INIT (TABLE_EXISTS_EXCEPTION, -955);
  312. BEGIN
  313. EXECUTE IMMEDIATE 'CREATE TABLE MOB_HISTORY (
  314. HISTORY_ID int PRIMARY KEY NOT NULL, -- identity
  315. EVENT_TIME timestamp NULL,
  316. EVENT_CODE int NOT NULL,
  317. ARGUMENTS varchar (1000) NULL
  318. )';
  319. EXECUTE IMMEDIATE 'CREATE INDEX IDX_HISTORY_CODE ON MOB_HISTORY(EVENT_CODE)';
  320. EXECUTE IMMEDIATE 'CREATE INDEX IDX_HISTORY_TIME ON MOB_HISTORY(EVENT_TIME)';
  321. EXCEPTION
  322. WHEN TABLE_EXISTS_EXCEPTION THEN
  323. NULL;
  324. END;
  325. /
  326. DECLARE
  327. SEQUENCE_EXISTS_EXCEPTION EXCEPTION;
  328. PRAGMA EXCEPTION_INIT (SEQUENCE_EXISTS_EXCEPTION, -955);
  329. BEGIN
  330. EXECUTE IMMEDIATE 'CREATE SEQUENCE SEQ_MOB_HISTORY START WITH 1 INCREMENT BY 1 NOMAXVALUE';
  331. EXCEPTION
  332. WHEN OTHERS THEN
  333. NULL;
  334. END;
  335. /
  336. CREATE OR REPLACE TRIGGER "TRIGGER_MOB_HISTORY" BEFORE INSERT ON "MOB_HISTORY" FOR EACH ROW
  337. BEGIN
  338. SELECT SEQ_MOB_HISTORY.nextval INTO :new.HISTORY_ID FROM DUAL;
  339. END;
  340. /
  341. -- MOB_USER_HISTORY
  342. DECLARE
  343. TABLE_EXISTS_EXCEPTION EXCEPTION;
  344. PRAGMA EXCEPTION_INIT (TABLE_EXISTS_EXCEPTION, -955);
  345. BEGIN
  346. EXECUTE IMMEDIATE 'CREATE TABLE MOB_USER_HISTORY (
  347. USER_ID int NOT NULL,
  348. HISTORY_ID int NOT NULL,
  349. CONSTRAINT FK_MOB_UH_UID FOREIGN KEY(USER_ID) REFERENCES MOB_USERS(USER_ID) ON DELETE CASCADE,
  350. CONSTRAINT FK_MOB_UH_HID FOREIGN KEY(HISTORY_ID) REFERENCES MOB_HISTORY(HISTORY_ID) ON DELETE CASCADE,
  351. CONSTRAINT PK_MOB_UH_UID PRIMARY KEY(USER_ID, HISTORY_ID)
  352. )';
  353. EXECUTE IMMEDIATE 'CREATE INDEX IDX_HIST_USER_ID ON MOB_USER_HISTORY(USER_ID)';
  354. EXCEPTION
  355. WHEN TABLE_EXISTS_EXCEPTION THEN
  356. NULL;
  357. END;
  358. /
  359. -- MOB_RENDER_HISTORY
  360. DECLARE
  361. TABLE_EXISTS_EXCEPTION EXCEPTION;
  362. PRAGMA EXCEPTION_INIT (TABLE_EXISTS_EXCEPTION, -955);
  363. BEGIN
  364. EXECUTE IMMEDIATE 'CREATE TABLE MOB_RENDER_HISTORY (
  365. RENDER_ID int NOT NULL,
  366. HISTORY_ID int NOT NULL,
  367. CONSTRAINT FK_MOB_RH_RID FOREIGN KEY(RENDER_ID) REFERENCES MOB_RENDERS(RENDER_ID) ON DELETE CASCADE,
  368. CONSTRAINT FK_MOB_RH_HID FOREIGN KEY(HISTORY_ID) REFERENCES MOB_HISTORY(HISTORY_ID) ON DELETE CASCADE
  369. )';
  370. EXECUTE IMMEDIATE 'CREATE INDEX IDX_MOB_RH_RID ON MOB_RENDER_HISTORY(RENDER_ID)';
  371. EXCEPTION
  372. WHEN TABLE_EXISTS_EXCEPTION THEN
  373. NULL;
  374. END;
  375. /