|
1 | 1 | CREATE TABLE executions_visibility (
|
2 |
| - namespace_id CHAR(64) NOT NULL, |
3 |
| - run_id CHAR(64) NOT NULL, |
4 |
| - start_time TIMESTAMP NOT NULL, |
5 |
| - execution_time TIMESTAMP NOT NULL, |
6 |
| - workflow_id VARCHAR(255) NOT NULL, |
7 |
| - workflow_type_name VARCHAR(255) NOT NULL, |
8 |
| - status INT NOT NULL, -- enum WorkflowExecutionStatus {RUNNING, COMPLETED, FAILED, CANCELED, TERMINATED, CONTINUED_AS_NEW, TIMED_OUT} |
9 |
| - close_time TIMESTAMP NULL, |
10 |
| - history_length BIGINT, |
11 |
| - memo BLOB, |
12 |
| - encoding VARCHAR(64) NOT NULL, |
13 |
| - task_queue VARCHAR(255) DEFAULT '' NOT NULL, |
14 |
| - |
15 |
| - PRIMARY KEY (namespace_id, run_id) |
| 2 | + namespace_id CHAR(64) NOT NULL, |
| 3 | + run_id CHAR(64) NOT NULL, |
| 4 | + start_time TIMESTAMP NOT NULL, |
| 5 | + execution_time TIMESTAMP NOT NULL, |
| 6 | + workflow_id VARCHAR(255) NOT NULL, |
| 7 | + workflow_type_name VARCHAR(255) NOT NULL, |
| 8 | + status INT NOT NULL, -- enum WorkflowExecutionStatus {RUNNING, COMPLETED, FAILED, CANCELED, TERMINATED, CONTINUED_AS_NEW, TIMED_OUT} |
| 9 | + close_time TIMESTAMP NULL, |
| 10 | + history_length BIGINT NULL, |
| 11 | + memo BLOB NULL, |
| 12 | + encoding VARCHAR(64) NOT NULL, |
| 13 | + task_queue VARCHAR(255) NOT NULL DEFAULT '', |
| 14 | + search_attributes TEXT NULL, |
| 15 | + |
| 16 | + -- Predefined search attributes |
| 17 | + TemporalChangeVersion TEXT GENERATED ALWAYS AS (JSON_EXTRACT(search_attributes, "$.TemporalChangeVersion")) STORED, |
| 18 | + BinaryChecksums TEXT GENERATED ALWAYS AS (JSON_EXTRACT(search_attributes, "$.BinaryChecksums")) STORED, |
| 19 | + BatcherUser VARCHAR(255) GENERATED ALWAYS AS (JSON_EXTRACT(search_attributes, "$.BatcherUser")), |
| 20 | + TemporalScheduledStartTime TIMESTAMP GENERATED ALWAYS AS (STRFTIME('%Y-%m-%d %H:%M%:%f+00:00', JSON_EXTRACT(search_attributes, "$.TemporalScheduledStartTime"))), |
| 21 | + TemporalScheduledById VARCHAR(255) GENERATED ALWAYS AS (JSON_EXTRACT(search_attributes, "$.TemporalScheduledById")), |
| 22 | + TemporalSchedulePaused BOOLEAN GENERATED ALWAYS AS (JSON_EXTRACT(search_attributes, "$.TemporalSchedulePaused")), |
| 23 | + TemporalNamespaceDivision VARCHAR(255) GENERATED ALWAYS AS (JSON_EXTRACT(search_attributes, "$.TemporalNamespaceDivision")), |
| 24 | + |
| 25 | + -- Pre-allocated custom search attributes |
| 26 | + Bool01 BOOLEAN GENERATED ALWAYS AS (JSON_EXTRACT(search_attributes, "$.Bool01")), |
| 27 | + Bool02 BOOLEAN GENERATED ALWAYS AS (JSON_EXTRACT(search_attributes, "$.Bool02")), |
| 28 | + Bool03 BOOLEAN GENERATED ALWAYS AS (JSON_EXTRACT(search_attributes, "$.Bool03")), |
| 29 | + Datetime01 TIMESTAMP GENERATED ALWAYS AS (STRFTIME('%Y-%m-%d %H:%M%:%f+00:00', JSON_EXTRACT(search_attributes, "$.Datetime01"))), |
| 30 | + Datetime02 TIMESTAMP GENERATED ALWAYS AS (STRFTIME('%Y-%m-%d %H:%M%:%f+00:00', JSON_EXTRACT(search_attributes, "$.Datetime02"))), |
| 31 | + Datetime03 TIMESTAMP GENERATED ALWAYS AS (STRFTIME('%Y-%m-%d %H:%M%:%f+00:00', JSON_EXTRACT(search_attributes, "$.Datetime03"))), |
| 32 | + Double01 DECIMAL(20, 5) GENERATED ALWAYS AS (JSON_EXTRACT(search_attributes, "$.Double01")), |
| 33 | + Double02 DECIMAL(20, 5) GENERATED ALWAYS AS (JSON_EXTRACT(search_attributes, "$.Double02")), |
| 34 | + Double03 DECIMAL(20, 5) GENERATED ALWAYS AS (JSON_EXTRACT(search_attributes, "$.Double03")), |
| 35 | + Int01 BIGINT GENERATED ALWAYS AS (JSON_EXTRACT(search_attributes, "$.Int01")), |
| 36 | + Int02 BIGINT GENERATED ALWAYS AS (JSON_EXTRACT(search_attributes, "$.Int02")), |
| 37 | + Int03 BIGINT GENERATED ALWAYS AS (JSON_EXTRACT(search_attributes, "$.Int03")), |
| 38 | + Keyword01 VARCHAR(255) GENERATED ALWAYS AS (JSON_EXTRACT(search_attributes, "$.Keyword01")), |
| 39 | + Keyword02 VARCHAR(255) GENERATED ALWAYS AS (JSON_EXTRACT(search_attributes, "$.Keyword02")), |
| 40 | + Keyword03 VARCHAR(255) GENERATED ALWAYS AS (JSON_EXTRACT(search_attributes, "$.Keyword03")), |
| 41 | + Keyword04 VARCHAR(255) GENERATED ALWAYS AS (JSON_EXTRACT(search_attributes, "$.Keyword04")), |
| 42 | + Keyword05 VARCHAR(255) GENERATED ALWAYS AS (JSON_EXTRACT(search_attributes, "$.Keyword05")), |
| 43 | + Keyword06 VARCHAR(255) GENERATED ALWAYS AS (JSON_EXTRACT(search_attributes, "$.Keyword06")), |
| 44 | + Keyword07 VARCHAR(255) GENERATED ALWAYS AS (JSON_EXTRACT(search_attributes, "$.Keyword07")), |
| 45 | + Keyword08 VARCHAR(255) GENERATED ALWAYS AS (JSON_EXTRACT(search_attributes, "$.Keyword08")), |
| 46 | + Keyword09 VARCHAR(255) GENERATED ALWAYS AS (JSON_EXTRACT(search_attributes, "$.Keyword09")), |
| 47 | + Keyword10 VARCHAR(255) GENERATED ALWAYS AS (JSON_EXTRACT(search_attributes, "$.Keyword10")), |
| 48 | + Text01 TEXT GENERATED ALWAYS AS (JSON_EXTRACT(search_attributes, "$.Text01")) STORED, |
| 49 | + Text02 TEXT GENERATED ALWAYS AS (JSON_EXTRACT(search_attributes, "$.Text02")) STORED, |
| 50 | + Text03 TEXT GENERATED ALWAYS AS (JSON_EXTRACT(search_attributes, "$.Text03")) STORED, |
| 51 | + KeywordList01 TEXT GENERATED ALWAYS AS (JSON_EXTRACT(search_attributes, "$.KeywordList01")) STORED, |
| 52 | + KeywordList02 TEXT GENERATED ALWAYS AS (JSON_EXTRACT(search_attributes, "$.KeywordList02")) STORED, |
| 53 | + KeywordList03 TEXT GENERATED ALWAYS AS (JSON_EXTRACT(search_attributes, "$.KeywordList03")) STORED, |
| 54 | + |
| 55 | + PRIMARY KEY (namespace_id, run_id) |
| 56 | +); |
| 57 | + |
| 58 | +CREATE INDEX default_idx ON executions_visibility (namespace_id, (COALESCE(close_time, '9999-12-31 23:59:59+00:00')) DESC, start_time DESC, run_id); |
| 59 | +CREATE INDEX by_execution_time ON executions_visibility (namespace_id, execution_time, (COALESCE(close_time, '9999-12-31 23:59:59+00:00')) DESC, start_time DESC, run_id); |
| 60 | +CREATE INDEX by_workflow_id ON executions_visibility (namespace_id, workflow_id, (COALESCE(close_time, '9999-12-31 23:59:59+00:00')) DESC, start_time DESC, run_id); |
| 61 | +CREATE INDEX by_workflow_type ON executions_visibility (namespace_id, workflow_type_name, (COALESCE(close_time, '9999-12-31 23:59:59+00:00')) DESC, start_time DESC, run_id); |
| 62 | +CREATE INDEX by_status ON executions_visibility (namespace_id, status, (COALESCE(close_time, '9999-12-31 23:59:59+00:00')) DESC, start_time DESC, run_id); |
| 63 | +CREATE INDEX by_history_length ON executions_visibility (namespace_id, history_length, (COALESCE(close_time, '9999-12-31 23:59:59+00:00')) DESC, start_time DESC, run_id); |
| 64 | +CREATE INDEX by_task_queue ON executions_visibility (namespace_id, task_queue, (COALESCE(close_time, '9999-12-31 23:59:59+00:00')) DESC, start_time DESC, run_id); |
| 65 | + |
| 66 | +-- Indexes for the predefined search attributes |
| 67 | +CREATE INDEX by_batcher_user ON executions_visibility (namespace_id, BatcherUser, (COALESCE(close_time, '9999-12-31 23:59:59+00:00')) DESC, start_time DESC, run_id); |
| 68 | +CREATE INDEX by_temporal_scheduled_start_time ON executions_visibility (namespace_id, TemporalScheduledStartTime, (COALESCE(close_time, '9999-12-31 23:59:59+00:00')) DESC, start_time DESC, run_id); |
| 69 | +CREATE INDEX by_temporal_scheduled_by_id ON executions_visibility (namespace_id, TemporalScheduledById, (COALESCE(close_time, '9999-12-31 23:59:59+00:00')) DESC, start_time DESC, run_id); |
| 70 | +CREATE INDEX by_temporal_schedule_paused ON executions_visibility (namespace_id, TemporalSchedulePaused, (COALESCE(close_time, '9999-12-31 23:59:59+00:00')) DESC, start_time DESC, run_id); |
| 71 | +CREATE INDEX by_temporal_namespace_division ON executions_visibility (namespace_id, TemporalNamespaceDivision, (COALESCE(close_time, '9999-12-31 23:59:59+00:00')) DESC, start_time DESC, run_id); |
| 72 | + |
| 73 | + |
| 74 | +-- Indexes for the pre-allocated custom search attributes |
| 75 | +CREATE INDEX by_bool_01 ON executions_visibility (namespace_id, Bool01, (COALESCE(close_time, '9999-12-31 23:59:59+00:00')) DESC, start_time DESC, run_id); |
| 76 | +CREATE INDEX by_bool_02 ON executions_visibility (namespace_id, Bool02, (COALESCE(close_time, '9999-12-31 23:59:59+00:00')) DESC, start_time DESC, run_id); |
| 77 | +CREATE INDEX by_bool_03 ON executions_visibility (namespace_id, Bool03, (COALESCE(close_time, '9999-12-31 23:59:59+00:00')) DESC, start_time DESC, run_id); |
| 78 | +CREATE INDEX by_datetime_01 ON executions_visibility (namespace_id, Datetime01, (COALESCE(close_time, '9999-12-31 23:59:59+00:00')) DESC, start_time DESC, run_id); |
| 79 | +CREATE INDEX by_datetime_02 ON executions_visibility (namespace_id, Datetime02, (COALESCE(close_time, '9999-12-31 23:59:59+00:00')) DESC, start_time DESC, run_id); |
| 80 | +CREATE INDEX by_datetime_03 ON executions_visibility (namespace_id, Datetime03, (COALESCE(close_time, '9999-12-31 23:59:59+00:00')) DESC, start_time DESC, run_id); |
| 81 | +CREATE INDEX by_double_01 ON executions_visibility (namespace_id, Double01, (COALESCE(close_time, '9999-12-31 23:59:59+00:00')) DESC, start_time DESC, run_id); |
| 82 | +CREATE INDEX by_double_02 ON executions_visibility (namespace_id, Double02, (COALESCE(close_time, '9999-12-31 23:59:59+00:00')) DESC, start_time DESC, run_id); |
| 83 | +CREATE INDEX by_double_03 ON executions_visibility (namespace_id, Double03, (COALESCE(close_time, '9999-12-31 23:59:59+00:00')) DESC, start_time DESC, run_id); |
| 84 | +CREATE INDEX by_int_01 ON executions_visibility (namespace_id, Int01, (COALESCE(close_time, '9999-12-31 23:59:59+00:00')) DESC, start_time DESC, run_id); |
| 85 | +CREATE INDEX by_int_02 ON executions_visibility (namespace_id, Int02, (COALESCE(close_time, '9999-12-31 23:59:59+00:00')) DESC, start_time DESC, run_id); |
| 86 | +CREATE INDEX by_int_03 ON executions_visibility (namespace_id, Int03, (COALESCE(close_time, '9999-12-31 23:59:59+00:00')) DESC, start_time DESC, run_id); |
| 87 | +CREATE INDEX by_keyword_01 ON executions_visibility (namespace_id, Keyword01, (COALESCE(close_time, '9999-12-31 23:59:59+00:00')) DESC, start_time DESC, run_id); |
| 88 | +CREATE INDEX by_keyword_02 ON executions_visibility (namespace_id, Keyword02, (COALESCE(close_time, '9999-12-31 23:59:59+00:00')) DESC, start_time DESC, run_id); |
| 89 | +CREATE INDEX by_keyword_03 ON executions_visibility (namespace_id, Keyword03, (COALESCE(close_time, '9999-12-31 23:59:59+00:00')) DESC, start_time DESC, run_id); |
| 90 | +CREATE INDEX by_keyword_04 ON executions_visibility (namespace_id, Keyword04, (COALESCE(close_time, '9999-12-31 23:59:59+00:00')) DESC, start_time DESC, run_id); |
| 91 | +CREATE INDEX by_keyword_05 ON executions_visibility (namespace_id, Keyword05, (COALESCE(close_time, '9999-12-31 23:59:59+00:00')) DESC, start_time DESC, run_id); |
| 92 | +CREATE INDEX by_keyword_06 ON executions_visibility (namespace_id, Keyword06, (COALESCE(close_time, '9999-12-31 23:59:59+00:00')) DESC, start_time DESC, run_id); |
| 93 | +CREATE INDEX by_keyword_07 ON executions_visibility (namespace_id, Keyword07, (COALESCE(close_time, '9999-12-31 23:59:59+00:00')) DESC, start_time DESC, run_id); |
| 94 | +CREATE INDEX by_keyword_08 ON executions_visibility (namespace_id, Keyword08, (COALESCE(close_time, '9999-12-31 23:59:59+00:00')) DESC, start_time DESC, run_id); |
| 95 | +CREATE INDEX by_keyword_09 ON executions_visibility (namespace_id, Keyword09, (COALESCE(close_time, '9999-12-31 23:59:59+00:00')) DESC, start_time DESC, run_id); |
| 96 | +CREATE INDEX by_keyword_10 ON executions_visibility (namespace_id, Keyword10, (COALESCE(close_time, '9999-12-31 23:59:59+00:00')) DESC, start_time DESC, run_id); |
| 97 | + |
| 98 | + |
| 99 | +CREATE VIRTUAL TABLE executions_visibility_fts_text USING fts5 ( |
| 100 | + Text01, |
| 101 | + Text02, |
| 102 | + Text03, |
| 103 | + content='executions_visibility', |
| 104 | + tokenize="unicode61 remove_diacritics 2" |
16 | 105 | );
|
17 | 106 |
|
18 |
| -CREATE INDEX by_type_start_time ON executions_visibility (namespace_id, workflow_type_name, status, start_time DESC, run_id); |
19 |
| -CREATE INDEX by_workflow_id_start_time ON executions_visibility (namespace_id, workflow_id, status, start_time DESC, run_id); |
20 |
| -CREATE INDEX by_status_by_start_time ON executions_visibility (namespace_id, status, start_time DESC, run_id); |
21 |
| -CREATE INDEX by_type_close_time ON executions_visibility (namespace_id, workflow_type_name, status, close_time DESC, run_id); |
22 |
| -CREATE INDEX by_workflow_id_close_time ON executions_visibility (namespace_id, workflow_id, status, close_time DESC, run_id); |
23 |
| -CREATE INDEX by_status_by_close_time ON executions_visibility (namespace_id, status, close_time DESC, run_id); |
24 |
| -CREATE INDEX by_close_time_by_status ON executions_visibility (namespace_id, close_time DESC, run_id, status); |
| 107 | +-- tokenize args: |
| 108 | +-- `unicode61`: accepts unicode chars |
| 109 | +-- `remove_diacritics 0`: don't remove diacritics, ie., 'a' is different than 'á' |
| 110 | +-- `categories 'C* L* M* N* P* S* Z*'`: all chars in all unicode categories are tokens |
| 111 | +-- `separators '♡'`: only the heart symbol (U+2661) is a token separator |
| 112 | +CREATE VIRTUAL TABLE executions_visibility_fts_keyword_list USING fts5 ( |
| 113 | + TemporalChangeVersion, |
| 114 | + BinaryChecksums, |
| 115 | + KeywordList01, |
| 116 | + KeywordList02, |
| 117 | + KeywordList03, |
| 118 | + content='executions_visibility', |
| 119 | + tokenize="unicode61 remove_diacritics 0 categories 'C* L* M* N* P* S* Z*' separators '♡'" |
| 120 | +); |
| 121 | + |
| 122 | +CREATE TRIGGER executions_visibility_ai AFTER INSERT ON executions_visibility |
| 123 | +BEGIN |
| 124 | + -- insert into fts_text table |
| 125 | + INSERT INTO executions_visibility_fts_text ( |
| 126 | + rowid, |
| 127 | + Text01, |
| 128 | + Text02, |
| 129 | + Text03 |
| 130 | + ) VALUES ( |
| 131 | + NEW.rowid, |
| 132 | + NEW.Text01, |
| 133 | + NEW.Text02, |
| 134 | + NEW.Text03 |
| 135 | + ); |
| 136 | + -- insert into fts_keyword_list table |
| 137 | + INSERT INTO executions_visibility_fts_keyword_list ( |
| 138 | + rowid, |
| 139 | + TemporalChangeVersion, |
| 140 | + BinaryChecksums, |
| 141 | + KeywordList01, |
| 142 | + KeywordList02, |
| 143 | + KeywordList03 |
| 144 | + ) VALUES ( |
| 145 | + NEW.rowid, |
| 146 | + NEW.TemporalChangeVersion, |
| 147 | + NEW.BinaryChecksums, |
| 148 | + NEW.KeywordList01, |
| 149 | + NEW.KeywordList02, |
| 150 | + NEW.KeywordList03 |
| 151 | + ); |
| 152 | +END; |
| 153 | + |
| 154 | +CREATE TRIGGER executions_visibility_ad AFTER DELETE ON executions_visibility |
| 155 | +BEGIN |
| 156 | + -- delete from fts_text table |
| 157 | + INSERT INTO executions_visibility_fts_text ( |
| 158 | + executions_visibility_fts_text, |
| 159 | + rowid, |
| 160 | + Text01, |
| 161 | + Text02, |
| 162 | + Text03 |
| 163 | + ) VALUES ( |
| 164 | + 'delete', |
| 165 | + OLD.rowid, |
| 166 | + OLD.Text01, |
| 167 | + OLD.Text02, |
| 168 | + OLD.Text03 |
| 169 | + ); |
| 170 | + -- delete from fts_keyword_list table |
| 171 | + INSERT INTO executions_visibility_fts_keyword_list ( |
| 172 | + executions_visibility_fts_keyword_list, |
| 173 | + rowid, |
| 174 | + TemporalChangeVersion, |
| 175 | + BinaryChecksums, |
| 176 | + KeywordList01, |
| 177 | + KeywordList02, |
| 178 | + KeywordList03 |
| 179 | + ) VALUES ( |
| 180 | + 'delete', |
| 181 | + OLD.rowid, |
| 182 | + OLD.TemporalChangeVersion, |
| 183 | + OLD.BinaryChecksums, |
| 184 | + OLD.KeywordList01, |
| 185 | + OLD.KeywordList02, |
| 186 | + OLD.KeywordList03 |
| 187 | + ); |
| 188 | +END; |
| 189 | + |
| 190 | +CREATE TRIGGER executions_visibility_au AFTER UPDATE ON executions_visibility |
| 191 | +BEGIN |
| 192 | + -- update fts_text table |
| 193 | + INSERT INTO executions_visibility_fts_text ( |
| 194 | + executions_visibility_fts_text, |
| 195 | + rowid, |
| 196 | + Text01, |
| 197 | + Text02, |
| 198 | + Text03 |
| 199 | + ) VALUES ( |
| 200 | + 'delete', |
| 201 | + OLD.rowid, |
| 202 | + OLD.Text01, |
| 203 | + OLD.Text02, |
| 204 | + OLD.Text03 |
| 205 | + ); |
| 206 | + INSERT INTO executions_visibility_fts_text ( |
| 207 | + rowid, |
| 208 | + Text01, |
| 209 | + Text02, |
| 210 | + Text03 |
| 211 | + ) VALUES ( |
| 212 | + NEW.rowid, |
| 213 | + NEW.Text01, |
| 214 | + NEW.Text02, |
| 215 | + NEW.Text03 |
| 216 | + ); |
| 217 | + -- update fts_keyword_list table |
| 218 | + INSERT INTO executions_visibility_fts_keyword_list ( |
| 219 | + executions_visibility_fts_keyword_list, |
| 220 | + rowid, |
| 221 | + TemporalChangeVersion, |
| 222 | + BinaryChecksums, |
| 223 | + KeywordList01, |
| 224 | + KeywordList02, |
| 225 | + KeywordList03 |
| 226 | + ) VALUES ( |
| 227 | + 'delete', |
| 228 | + OLD.rowid, |
| 229 | + OLD.TemporalChangeVersion, |
| 230 | + OLD.BinaryChecksums, |
| 231 | + OLD.KeywordList01, |
| 232 | + OLD.KeywordList02, |
| 233 | + OLD.KeywordList03 |
| 234 | + ); |
| 235 | + INSERT INTO executions_visibility_fts_keyword_list ( |
| 236 | + rowid, |
| 237 | + TemporalChangeVersion, |
| 238 | + BinaryChecksums, |
| 239 | + KeywordList01, |
| 240 | + KeywordList02, |
| 241 | + KeywordList03 |
| 242 | + ) VALUES ( |
| 243 | + NEW.rowid, |
| 244 | + NEW.TemporalChangeVersion, |
| 245 | + NEW.BinaryChecksums, |
| 246 | + NEW.KeywordList01, |
| 247 | + NEW.KeywordList02, |
| 248 | + NEW.KeywordList03 |
| 249 | + ); |
| 250 | +END; |
0 commit comments