|
1 | 1 | DROP TABLE IF EXISTS matrices;
|
| 2 | + |
2 | 3 | CREATE TEMPORARY TABLE matrices AS
|
3 |
| - SELECT board, ( |
4 |
| - WITH RECURSIVE split_lines (string, line) AS ( |
5 |
| - VALUES (board||CHAR(10), NULL) |
6 |
| - UNION ALL |
7 |
| - SELECT SUBSTR(string, INSTR(string, CHAR(10)) + 1), |
8 |
| - SUBSTR(string, 1, INSTR(string, CHAR(10)) - 1) |
9 |
| - FROM split_lines |
10 |
| - WHERE string <> '' |
11 |
| - ) |
12 |
| - SELECT JSON_GROUP_ARRAY(( |
13 |
| - WITH RECURSIVE split_letters (string, letter) AS ( |
14 |
| - VALUES (line, NULL) |
| 4 | +SELECT |
| 5 | + board, |
| 6 | + ( |
| 7 | + WITH RECURSIVE |
| 8 | + split_lines (string, line) AS ( |
| 9 | + VALUES |
| 10 | + (board || CHAR(10), NULL) |
15 | 11 | UNION ALL
|
16 |
| - SELECT SUBSTR(string, 2), SUBSTR(string, 1, 1) |
17 |
| - FROM split_letters |
18 |
| - WHERE string <> '' |
| 12 | + SELECT |
| 13 | + SUBSTR(string, INSTR(string, CHAR(10)) + 1), |
| 14 | + SUBSTR(string, 1, INSTR(string, CHAR(10)) - 1) |
| 15 | + FROM |
| 16 | + split_lines |
| 17 | + WHERE |
| 18 | + string <> '' |
19 | 19 | )
|
20 |
| - SELECT JSON_GROUP_ARRAY(letter) letters |
21 |
| - FROM split_letters |
22 |
| - WHERE letter NOTNULL |
23 |
| - )) matrix |
24 |
| - FROM split_lines |
25 |
| - WHERE line NOTNULL |
| 20 | + SELECT |
| 21 | + JSON_GROUP_ARRAY( |
| 22 | + ( |
| 23 | + WITH RECURSIVE |
| 24 | + split_letters (string, letter) AS ( |
| 25 | + VALUES |
| 26 | + (line, NULL) |
| 27 | + UNION ALL |
| 28 | + SELECT |
| 29 | + SUBSTR(string, 2), |
| 30 | + SUBSTR(string, 1, 1) |
| 31 | + FROM |
| 32 | + split_letters |
| 33 | + WHERE |
| 34 | + string <> '' |
| 35 | + ) |
| 36 | + SELECT |
| 37 | + JSON_GROUP_ARRAY(letter) letters |
| 38 | + FROM |
| 39 | + split_letters |
| 40 | + WHERE |
| 41 | + letter NOTNULL |
| 42 | + ) |
| 43 | + ) matrix |
| 44 | + FROM |
| 45 | + split_lines |
| 46 | + WHERE |
| 47 | + line NOTNULL |
26 | 48 | ) matrix
|
27 |
| - FROM "state-of-tic-tac-toe"; |
| 49 | +FROM |
| 50 | + "state-of-tic-tac-toe"; |
28 | 51 |
|
29 |
| -ALTER TABLE matrices ADD has_win TEXT; |
| 52 | +ALTER TABLE matrices |
| 53 | +ADD has_win TEXT; |
30 | 54 |
|
31 | 55 | UPDATE matrices
|
32 |
| - SET has_win = ( |
33 |
| - SELECT JSON_GROUP_ARRAY(JSON(won)) |
34 |
| - FROM ( |
35 |
| - SELECT j.value AS won FROM JSON_EACH(matrix) j |
36 |
| - UNION |
37 |
| - SELECT JSON_GROUP_ARRAY(JSON_EXTRACT(j.value, '$[0]')) |
38 |
| - FROM JSON_EACH(matrix) j |
39 |
| - UNION |
40 |
| - SELECT JSON_GROUP_ARRAY(JSON_EXTRACT(j.value, '$[1]')) |
41 |
| - FROM JSON_EACH(matrix) j |
42 |
| - UNION |
43 |
| - SELECT JSON_GROUP_ARRAY(JSON_EXTRACT(j.value, '$[2]')) |
44 |
| - FROM JSON_EACH(matrix) j |
45 |
| - UNION |
46 |
| - SELECT |
47 |
| - JSON_ARRAY( |
48 |
| - JSON_EXTRACT(matrix, '$[0][0]'), |
49 |
| - JSON_EXTRACT(matrix, '$[1][1]'), |
50 |
| - JSON_EXTRACT(matrix, '$[2][2]') |
51 |
| - ) |
52 |
| - UNION |
53 |
| - SELECT |
54 |
| - JSON_ARRAY( |
55 |
| - JSON_EXTRACT(matrix, '$[0][2]'), |
56 |
| - JSON_EXTRACT(matrix, '$[1][1]'), |
57 |
| - JSON_EXTRACT(matrix, '$[2][0]') |
58 |
| - ) |
59 |
| - ) |
60 |
| - WHERE won IN ('["X","X","X"]', '["O","O","O"]') |
61 |
| - ); |
| 56 | +SET |
| 57 | + has_win = ( |
| 58 | + SELECT |
| 59 | + JSON_GROUP_ARRAY(JSON(won)) |
| 60 | + FROM |
| 61 | + ( |
| 62 | + SELECT |
| 63 | + j.value AS won |
| 64 | + FROM |
| 65 | + JSON_EACH(matrix) j |
| 66 | + UNION |
| 67 | + SELECT |
| 68 | + JSON_GROUP_ARRAY(JSON_EXTRACT(j.value, '$[0]')) |
| 69 | + FROM |
| 70 | + JSON_EACH(matrix) j |
| 71 | + UNION |
| 72 | + SELECT |
| 73 | + JSON_GROUP_ARRAY(JSON_EXTRACT(j.value, '$[1]')) |
| 74 | + FROM |
| 75 | + JSON_EACH(matrix) j |
| 76 | + UNION |
| 77 | + SELECT |
| 78 | + JSON_GROUP_ARRAY(JSON_EXTRACT(j.value, '$[2]')) |
| 79 | + FROM |
| 80 | + JSON_EACH(matrix) j |
| 81 | + UNION |
| 82 | + SELECT |
| 83 | + JSON_ARRAY( |
| 84 | + JSON_EXTRACT(matrix, '$[0][0]'), |
| 85 | + JSON_EXTRACT(matrix, '$[1][1]'), |
| 86 | + JSON_EXTRACT(matrix, '$[2][2]') |
| 87 | + ) |
| 88 | + UNION |
| 89 | + SELECT |
| 90 | + JSON_ARRAY( |
| 91 | + JSON_EXTRACT(matrix, '$[0][2]'), |
| 92 | + JSON_EXTRACT(matrix, '$[1][1]'), |
| 93 | + JSON_EXTRACT(matrix, '$[2][0]') |
| 94 | + ) |
| 95 | + ) |
| 96 | + WHERE |
| 97 | + won IN ('["X","X","X"]', '["O","O","O"]') |
| 98 | + ); |
62 | 99 |
|
63 | 100 | UPDATE "state-of-tic-tac-toe" AS t
|
64 |
| - SET error = 'Wrong turn order: X went twice' |
65 |
| - FROM matrices AS m |
66 |
| - WHERE t.board = m.board |
67 |
| - AND ( |
68 |
| - WITH cte AS (SELECT j.value AS jrow FROM JSON_EACH(m.matrix) j) |
69 |
| - SELECT COUNT(*) FILTER (WHERE j.value = 'X') = |
70 |
| - COUNT(*) FILTER (WHERE j.value = 'O') + 2 |
71 |
| - FROM cte, JSON_EACH(jrow) j |
72 |
| - ) |
73 |
| -; |
| 101 | +SET |
| 102 | + error = 'Wrong turn order: X went twice' |
| 103 | +FROM |
| 104 | + matrices AS m |
| 105 | +WHERE |
| 106 | + t.board = m.board |
| 107 | + AND ( |
| 108 | + WITH |
| 109 | + cte AS ( |
| 110 | + SELECT |
| 111 | + j.value AS jrow |
| 112 | + FROM |
| 113 | + JSON_EACH(m.matrix) j |
| 114 | + ) |
| 115 | + SELECT |
| 116 | + COUNT(*) FILTER ( |
| 117 | + WHERE |
| 118 | + j.value = 'X' |
| 119 | + ) = COUNT(*) FILTER ( |
| 120 | + WHERE |
| 121 | + j.value = 'O' |
| 122 | + ) + 2 |
| 123 | + FROM |
| 124 | + cte, |
| 125 | + JSON_EACH(jrow) j |
| 126 | + ); |
74 | 127 |
|
75 | 128 | UPDATE "state-of-tic-tac-toe" AS t
|
76 |
| - SET error = 'Wrong turn order: O started' |
77 |
| - FROM matrices AS m |
78 |
| - WHERE t.board = m.board |
79 |
| - AND ( |
80 |
| - WITH cte AS (SELECT j.value AS jrow FROM JSON_EACH(m.matrix) j) |
81 |
| - SELECT COUNT(*) FILTER (WHERE j.value = 'O') = |
82 |
| - COUNT(*) FILTER (WHERE j.value = 'X') + 1 |
83 |
| - FROM cte, JSON_EACH(jrow) j |
84 |
| - ) |
85 |
| -; |
| 129 | +SET |
| 130 | + error = 'Wrong turn order: O started' |
| 131 | +FROM |
| 132 | + matrices AS m |
| 133 | +WHERE |
| 134 | + t.board = m.board |
| 135 | + AND ( |
| 136 | + WITH |
| 137 | + cte AS ( |
| 138 | + SELECT |
| 139 | + j.value AS jrow |
| 140 | + FROM |
| 141 | + JSON_EACH(m.matrix) j |
| 142 | + ) |
| 143 | + SELECT |
| 144 | + COUNT(*) FILTER ( |
| 145 | + WHERE |
| 146 | + j.value = 'O' |
| 147 | + ) = COUNT(*) FILTER ( |
| 148 | + WHERE |
| 149 | + j.value = 'X' |
| 150 | + ) + 1 |
| 151 | + FROM |
| 152 | + cte, |
| 153 | + JSON_EACH(jrow) j |
| 154 | + ); |
86 | 155 |
|
87 | 156 | UPDATE "state-of-tic-tac-toe" AS t
|
88 |
| - SET error = 'Impossible board: game should have ended after the game was won' |
89 |
| - FROM matrices AS m |
90 |
| - WHERE t.board = m.board |
91 |
| - AND JSON_ARRAY_LENGTH(m.has_win) = 2 |
92 |
| - AND ( |
93 |
| - WITH cte AS (SELECT j.value AS jrow FROM JSON_EACH(m.matrix) j) |
94 |
| - SELECT COUNT(*) <= 3 FROM cte, JSON_EACH(jrow) j WHERE j.value = ' ' |
95 |
| - ) |
96 |
| -; |
| 157 | +SET |
| 158 | + error = 'Impossible board: game should have ended after the game was won' |
| 159 | +FROM |
| 160 | + matrices AS m |
| 161 | +WHERE |
| 162 | + t.board = m.board |
| 163 | + AND JSON_ARRAY_LENGTH(m.has_win) = 2 |
| 164 | + AND ( |
| 165 | + WITH |
| 166 | + cte AS ( |
| 167 | + SELECT |
| 168 | + j.value AS jrow |
| 169 | + FROM |
| 170 | + JSON_EACH(m.matrix) j |
| 171 | + ) |
| 172 | + SELECT |
| 173 | + COUNT(*) <= 3 |
| 174 | + FROM |
| 175 | + cte, |
| 176 | + JSON_EACH(jrow) j |
| 177 | + WHERE |
| 178 | + j.value = ' ' |
| 179 | + ); |
97 | 180 |
|
98 | 181 | UPDATE "state-of-tic-tac-toe" AS t
|
99 |
| - SET result = 'win' |
100 |
| - FROM matrices AS m |
101 |
| - WHERE t.board = m.board |
102 |
| - AND t.error ISNULL |
103 |
| - AND JSON_ARRAY_LENGTH(m.has_win) = 1 |
104 |
| -; |
| 182 | +SET |
| 183 | + result = 'win' |
| 184 | +FROM |
| 185 | + matrices AS m |
| 186 | +WHERE |
| 187 | + t.board = m.board |
| 188 | + AND t.error ISNULL |
| 189 | + AND JSON_ARRAY_LENGTH(m.has_win) = 1; |
105 | 190 |
|
106 | 191 | UPDATE "state-of-tic-tac-toe" AS t
|
107 |
| - SET result = 'draw' |
108 |
| - FROM matrices AS m |
109 |
| - WHERE t.board = m.board |
110 |
| - AND t.error ISNULL |
111 |
| - AND JSON_ARRAY_LENGTH(m.has_win) = 0 |
112 |
| - AND ( |
113 |
| - WITH cte AS (SELECT j.value AS jrow FROM JSON_EACH(m.matrix) j) |
114 |
| - SELECT COUNT(*) = 0 FROM cte, JSON_EACH(jrow) j WHERE j.value = ' ' |
115 |
| - ) |
116 |
| -; |
| 192 | +SET |
| 193 | + result = 'draw' |
| 194 | +FROM |
| 195 | + matrices AS m |
| 196 | +WHERE |
| 197 | + t.board = m.board |
| 198 | + AND t.error ISNULL |
| 199 | + AND JSON_ARRAY_LENGTH(m.has_win) = 0 |
| 200 | + AND ( |
| 201 | + WITH |
| 202 | + cte AS ( |
| 203 | + SELECT |
| 204 | + j.value AS jrow |
| 205 | + FROM |
| 206 | + JSON_EACH(m.matrix) j |
| 207 | + ) |
| 208 | + SELECT |
| 209 | + COUNT(*) = 0 |
| 210 | + FROM |
| 211 | + cte, |
| 212 | + JSON_EACH(jrow) j |
| 213 | + WHERE |
| 214 | + j.value = ' ' |
| 215 | + ); |
117 | 216 |
|
118 | 217 | UPDATE "state-of-tic-tac-toe" AS t
|
119 |
| - SET result = 'ongoing' |
120 |
| - FROM matrices AS m |
121 |
| - WHERE t.board = m.board |
122 |
| - AND t.error ISNULL |
123 |
| - AND JSON_ARRAY_LENGTH(m.has_win) = 0 |
124 |
| - AND ( |
125 |
| - WITH cte AS (SELECT j.value AS jrow FROM JSON_EACH(m.matrix) j) |
126 |
| - SELECT COUNT(*) > 0 FROM cte, JSON_EACH(jrow) j WHERE j.value = ' ' |
127 |
| - ) |
128 |
| -; |
| 218 | +SET |
| 219 | + result = 'ongoing' |
| 220 | +FROM |
| 221 | + matrices AS m |
| 222 | +WHERE |
| 223 | + t.board = m.board |
| 224 | + AND t.error ISNULL |
| 225 | + AND JSON_ARRAY_LENGTH(m.has_win) = 0 |
| 226 | + AND ( |
| 227 | + WITH |
| 228 | + cte AS ( |
| 229 | + SELECT |
| 230 | + j.value AS jrow |
| 231 | + FROM |
| 232 | + JSON_EACH(m.matrix) j |
| 233 | + ) |
| 234 | + SELECT |
| 235 | + COUNT(*) > 0 |
| 236 | + FROM |
| 237 | + cte, |
| 238 | + JSON_EACH(jrow) j |
| 239 | + WHERE |
| 240 | + j.value = ' ' |
| 241 | + ); |
0 commit comments