upgrade-00-000-to-02-020.sql 6.6 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201
  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 IBM Informix.
  7. -- MOB_PORTALITEMS
  8. CREATE TABLE MOB_PORTALITEMS (
  9. PORTALITEM_ID SERIAL PRIMARY KEY,
  10. LABEL varchar (100),
  11. STORE_ID varchar (200),
  12. CM_PATH lvarchar (1000),
  13. SOURCE_PATH lvarchar (1000),
  14. DESCRIPTION lvarchar (500),
  15. PORTALITEM_TYPE int DEFAULT 0 NOT NULL
  16. );
  17. CREATE INDEX IDX_MOB_REP_SI ON MOB_PORTALITEMS(STORE_ID);
  18. -- MOB_RENDERS
  19. CREATE TABLE MOB_RENDERS (
  20. RENDER_ID SERIAL PRIMARY KEY,
  21. RENDER_TIME datetime YEAR TO SECOND NOT NULL,
  22. RENDER_SIZE int NOT NULL,
  23. STATUS_CODE int NOT NULL,
  24. SOURCE_CODE smallint,
  25. DRILL_PARAMS lvarchar (1000),
  26. PORTALITEM_ID int NOT NULL,
  27. BASE_DOC varchar (200),
  28. SMALL_THUMB varchar (200),
  29. MEDIUM_THUMB varchar (200),
  30. LARGE_THUMB varchar (200),
  31. SAVED_OUTPUT_TYPE smallint,
  32. CREATION_TIME datetime YEAR TO SECOND DEFAULT CURRENT YEAR TO SECOND NOT NULL,
  33. FOREIGN KEY(PORTALITEM_ID) REFERENCES MOB_PORTALITEMS(PORTALITEM_ID) ON DELETE CASCADE CONSTRAINT FK_MOB_R_PIID
  34. );
  35. -- MOB_USERS
  36. CREATE TABLE MOB_USERS (
  37. USER_ID SERIAL PRIMARY KEY CONSTRAINT USER_ID,
  38. DEVICE_ID varchar (100) NOT NULL,
  39. DEVICE_PROFILE varchar (200),
  40. CREDENTIAL_PATH varchar (200),
  41. CAM_ID varchar (100),
  42. KEY_TYPE varchar (20),
  43. KEY_BYTES blob (32),
  44. SYNC_METHOD varchar (20),
  45. LAST_LOGIN datetime YEAR TO SECOND,
  46. LAST_UPDATED datetime YEAR TO SECOND DEFAULT CURRENT YEAR TO SECOND NOT NULL
  47. );
  48. CREATE INDEX IDX_CAM_ID ON MOB_USERS(CAM_ID);
  49. -- MOB_TEMPSTORAGE
  50. CREATE TABLE MOB_TEMPSTORAGE (
  51. TS_ID SERIAL PRIMARY KEY CONSTRAINT TS_ID,
  52. PATH lvarchar (500),
  53. CREATED datetime YEAR TO SECOND NOT NULL,
  54. MODIFIED datetime YEAR TO SECOND NOT NULL
  55. );
  56. --CREATE INDEX PK_MOB_TS ON MOB_TEMPSTORAGE(TS_ID); --serial creates one
  57. CREATE INDEX IDX_MOB_MODIFIED ON MOB_TEMPSTORAGE(MODIFIED);
  58. CREATE INDEX IDX_MOB_CREATED ON MOB_TEMPSTORAGE(CREATED);
  59. CREATE INDEX IDX_MOB_TMPPATH ON MOB_TEMPSTORAGE(PATH);
  60. -- MOB_HISTORY
  61. CREATE TABLE MOB_HISTORY (
  62. HISTORY_ID SERIAL PRIMARY KEY CONSTRAINT HISTORY_ID,
  63. EVENT_TIME datetime YEAR TO SECOND,
  64. EVENT_CODE int NOT NULL,
  65. ARGUMENTS lvarchar (1000)
  66. );
  67. CREATE INDEX IDX_HISTORY_CODE ON MOB_HISTORY(EVENT_CODE);
  68. CREATE INDEX IDX_HISTORY_TIME ON MOB_HISTORY(EVENT_TIME);
  69. -- MOB_BLOBS
  70. CREATE TABLE MOB_BLOBS (
  71. HASH char (32),
  72. USER_ID int,
  73. SEQUENCE int NOT NULL,
  74. BLOB_VALUE blob (1024) NOT NULL,
  75. FORMAT smallint,
  76. ADDED datetime YEAR TO SECOND DEFAULT CURRENT YEAR TO SECOND NOT NULL,
  77. FOREIGN KEY(USER_ID) REFERENCES MOB_USERS(USER_ID) ON DELETE CASCADE CONSTRAINT FK_MOB_BLOBS_UID
  78. );
  79. CREATE INDEX IDX_MOB_BLOBS_HASH ON MOB_BLOBS(HASH);
  80. -- MOB_TEMPSTOREBLOBS
  81. CREATE TABLE MOB_TEMPSTOREBLOBS (
  82. TS_ID int NOT NULL,
  83. SEQUENCE int NOT NULL,
  84. BLOB_VALUE blob (1024) NOT NULL,
  85. FOREIGN KEY(TS_ID) REFERENCES MOB_TEMPSTORAGE(TS_ID) ON DELETE CASCADE CONSTRAINT FK_MOB_TSB_TSID
  86. );
  87. CREATE INDEX IDX_MOB_TSBLOBS2 ON MOB_TEMPSTOREBLOBS(TS_ID, SEQUENCE);
  88. -- MOB_USER_HISTORY
  89. CREATE TABLE MOB_USER_HISTORY (
  90. USER_ID int NOT NULL,
  91. HISTORY_ID int NOT NULL,
  92. FOREIGN KEY(USER_ID) REFERENCES MOB_USERS(USER_ID) ON DELETE CASCADE CONSTRAINT FK_MOB_UH_UID,
  93. FOREIGN KEY(HISTORY_ID) REFERENCES MOB_HISTORY(HISTORY_ID) ON DELETE CASCADE CONSTRAINT FK_MOB_UH_HID,
  94. PRIMARY KEY(USER_ID, HISTORY_ID) CONSTRAINT PK_MOB_UH_UID
  95. );
  96. --CREATE INDEX IDX_HIST_USER_ID ON MOB_USER_HISTORY(USER_ID); --already exists
  97. -- MOB_USER_RENDER
  98. CREATE TABLE MOB_USER_RENDER (
  99. USER_ID int NOT NULL,
  100. RENDER_ID int NOT NULL,
  101. NAME varchar (100),
  102. LAST_VIEWED datetime YEAR TO SECOND,
  103. FOREIGN KEY(USER_ID) REFERENCES MOB_USERS(USER_ID) ON DELETE CASCADE CONSTRAINT FK_MOB_UR_UID,
  104. FOREIGN KEY(RENDER_ID) REFERENCES MOB_RENDERS(RENDER_ID) ON DELETE CASCADE CONSTRAINT FK_MOB_UR_RID,
  105. PRIMARY KEY(USER_ID, RENDER_ID) CONSTRAINT PK_MOB_USERRNDR
  106. );
  107. -- MOB_USER_PORTALITEM
  108. CREATE TABLE MOB_USER_PORTALITEM (
  109. USER_ID int NOT NULL,
  110. PORTALITEM_ID int NOT NULL,
  111. USER_PORTALITEM_TYPE int DEFAULT 0 NOT NULL,
  112. FOREIGN KEY(USER_ID) REFERENCES MOB_USERS(USER_ID) ON DELETE CASCADE CONSTRAINT FK_MOB_UPI_UID,
  113. FOREIGN KEY(PORTALITEM_ID) REFERENCES MOB_PORTALITEMS(PORTALITEM_ID) ON DELETE CASCADE CONSTRAINT FK_MOB_UPI_RSID,
  114. PRIMARY KEY(USER_ID, PORTALITEM_ID, USER_PORTALITEM_TYPE) CONSTRAINT PK_MOB_USERPIID
  115. );
  116. CREATE TABLE MOB_RESOURCES (
  117. RESOURCE_ID SERIAL PRIMARY KEY,
  118. RENDER_ID int,
  119. PATH varchar (200),
  120. HASH char (32),
  121. FORMAT smallint,
  122. HEIGHT int,
  123. WIDTH int,
  124. BLOB_ID int,
  125. OBJECT_INDEX int,
  126. PAGE_INDEX int,
  127. FOREIGN KEY(RENDER_ID) REFERENCES MOB_RENDERS(RENDER_ID) ON DELETE CASCADE CONSTRAINT FK_MOB_RES_RID
  128. );
  129. -- CREATE INDEX IDX_MOB_RESOURCES ON MOB_RESOURCES(RENDER_ID); -- already exists
  130. -- MOB_RENDER_HISTORY
  131. CREATE TABLE MOB_RENDER_HISTORY (
  132. RENDER_ID int NOT NULL,
  133. HISTORY_ID int NOT NULL,
  134. FOREIGN KEY(RENDER_ID) REFERENCES MOB_RENDERS(RENDER_ID) ON DELETE CASCADE CONSTRAINT FK_MOB_RH_RID,
  135. FOREIGN KEY(HISTORY_ID) REFERENCES MOB_HISTORY(HISTORY_ID) ON DELETE CASCADE CONSTRAINT FK_MOB_RH_HID
  136. );
  137. -- CREATE INDEX IDX_MOB_RH_RID ON MOB_RENDER_HISTORY(RENDER_ID); -- already exists
  138. --CREATE TRIGGER TGR_M_UPI_SYNC_DE -- doesn't work with ON DELETE CASCADE
  139. --DELETE ON MOB_USER_PORTALITEM
  140. --REFERENCING OLD AS pre
  141. --FOR EACH ROW
  142. -- (UPDATE MOB_USERS SET LAST_UPDATED = CURRENT YEAR TO SECOND
  143. -- WHERE USER_ID = pre.USER_ID);
  144. CREATE TRIGGER TGR_M_UPI_SYNC_IN
  145. INSERT ON MOB_USER_PORTALITEM
  146. REFERENCING NEW AS pre
  147. FOR EACH ROW
  148. (UPDATE MOB_USERS SET LAST_UPDATED = CURRENT YEAR TO SECOND
  149. WHERE USER_ID = pre.USER_ID);
  150. CREATE TRIGGER TGR_M_UPI_SYNC_UP
  151. UPDATE ON MOB_USER_PORTALITEM
  152. REFERENCING NEW AS pre
  153. FOR EACH ROW
  154. (UPDATE MOB_USERS SET LAST_UPDATED = CURRENT YEAR TO SECOND
  155. WHERE USER_ID = pre.USER_ID);
  156. CREATE TRIGGER TGR_MOB_UR_SYNC_IN
  157. INSERT ON MOB_USER_RENDER
  158. REFERENCING NEW AS pre
  159. FOR EACH ROW
  160. (UPDATE MOB_USERS SET LAST_UPDATED = CURRENT YEAR TO SECOND
  161. WHERE USER_ID = pre.USER_ID);
  162. CREATE TRIGGER TGR_MOB_UR_SYNC_UP
  163. UPDATE ON MOB_USER_RENDER
  164. REFERENCING NEW AS pre
  165. FOR EACH ROW
  166. (UPDATE MOB_USERS SET LAST_UPDATED = CURRENT YEAR TO SECOND
  167. WHERE USER_ID = pre.USER_ID);
  168. --CREATE TRIGGER TGR_MOB_UR_SYNC_DE -- doesn't work with ON DELETE CASCADE
  169. --DELETE ON MOB_USER_RENDER
  170. --REFERENCING OLD AS pre
  171. --FOR EACH ROW
  172. -- (UPDATE MOB_USERS SET LAST_UPDATED = CURRENT YEAR TO SECOND
  173. -- WHERE USER_ID = pre.USER_ID);
  174. CREATE TABLE MOB_DRILLS (
  175. SOURCE_RENDER_ID int NOT NULL,
  176. TARGET_RENDER_ID int NOT NULL,
  177. DRILL_CONTEXT lvarchar (1000) NOT NULL,
  178. DRILL_TYPE smallint NOT NULL,
  179. FOREIGN KEY(SOURCE_RENDER_ID) REFERENCES MOB_RENDERS(RENDER_ID) ON DELETE CASCADE CONSTRAINT FK_MOB_D_SRID
  180. );