├── .github ├── actions │ └── Postgres.yml └── workflows │ └── stitch.yml ├── LICENSE ├── README.md ├── acid.sql ├── logo.svg ├── renderer.sql ├── stitch.sh ├── test_binary.py └── tests ├── compliance ├── test008.sql ├── test014.sql ├── test015.sql ├── test016.sql ├── test017.sql ├── test018.sql ├── test019.sql ├── test020.sql ├── test021.sql ├── test022.sql ├── test023.sql ├── test024.sql ├── test025.sql └── test027.sql └── convention ├── test001.sql ├── test002.sql ├── test003.sql ├── test004.sql ├── test005.sql ├── test006.sql ├── test007.sql ├── test009.sql ├── test010.sql ├── test011.sql ├── test012.sql ├── test013.sql └── test026.sql /.github/actions/Postgres.yml: -------------------------------------------------------------------------------- 1 | name: RuPostgresby 2 | 3 | on: 4 | push: 5 | pull_request: 6 | 7 | jobs: 8 | postgres: 9 | 10 | runs-on: ubuntu-latest 11 | 12 | services: 13 | postgres: 14 | image: postgres:latest 15 | env: 16 | POSTGRES_DB: postgres 17 | POSTGRES_USER: postgres 18 | POSTGRES_PASSWORD: postgres 19 | ports: 20 | - 5432:5432 21 | # Set health checks to wait until postgres has started 22 | options: 23 | --health-cmd pg_isready 24 | --health-interval 10s 25 | --health-timeout 5s 26 | --health-retries 5 27 | 28 | -------------------------------------------------------------------------------- /.github/workflows/stitch.yml: -------------------------------------------------------------------------------- 1 | name: stitch 2 | on: 3 | push: 4 | branches: [ "main" ] 5 | paths: [ "*.sql" ] 6 | pull_request: 7 | branches: [ "main" ] 8 | paths: [ "*.sql" ] 9 | workflow_dispatch: 10 | jobs: 11 | build: 12 | runs-on: ubuntu-latest 13 | steps: 14 | - uses: actions/checkout@v3 15 | - name: Run stitching script 16 | run: ./stitch.sh tests/**/*.sql > acid.sql 17 | - name: Check it does not deviate 18 | run: git diff --exit-code 19 | - name: Upload stitched result 20 | uses: actions/upload-artifact@v3 21 | with: 22 | name: acid 23 | path: acid.sql 24 | -------------------------------------------------------------------------------- /LICENSE: -------------------------------------------------------------------------------- 1 | MIT License 2 | 3 | Copyright (c) 2023 SQL Standards Project 4 | 5 | Permission is hereby granted, free of charge, to any person obtaining a copy 6 | of this software and associated documentation files (the "Software"), to deal 7 | in the Software without restriction, including without limitation the rights 8 | to use, copy, modify, merge, publish, distribute, sublicense, and/or sell 9 | copies of the Software, and to permit persons to whom the Software is 10 | furnished to do so, subject to the following conditions: 11 | 12 | The above copyright notice and this permission notice shall be included in all 13 | copies or substantial portions of the Software. 14 | 15 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR 16 | IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, 17 | FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE 18 | AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER 19 | LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, 20 | OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE 21 | SOFTWARE. 22 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 |
2 | 3 |
4 | 5 | # SQL Acid Test 6 | 7 | Despite the existence of the SQL standard, there are still many differences between different SQL engines. Some differences are due to ambiguities or lack of detail in the standard, others are due to historical or political reasons. Those differences make it very hard to write portable SQL queries and generally hinder progress. 8 | 9 | The SQL Acid Test defines a common sane understanding of details in SQL SELECT query semantics. This test is inspired by the influential [Acid2 test for Web browsers](https://en.wikipedia.org/wiki/Acid2). The test goes above and beyond the SQL standard and attempts to define sane, desireable behavior. The test should not be confused with the [ACID principles](https://en.wikipedia.org/wiki/ACID) for database transactions. 10 | 11 | Tests are written in standard SQL and compiled into a single query. If the tests pass, a smiley face as shown below is displayed. If tests fail, the image is either distorted or not shown at all due to errors in query evaluation. To test your specific SQL system, copy the query in the file `acid.sql` below and run it. 12 | 13 | ``` 14 | +-----------------+ 15 | |......#####......| 16 | |....##.....##....| 17 | |...#.........#...| 18 | |..#..()...()..#..| 19 | |..#.....o.....#..| 20 | |.#.............#.| 21 | |..#..\...../..#..| 22 | |..#...-----...#..| 23 | |...#.........#...| 24 | |....##.....##....| 25 | |......#####......| 26 | +-----------------+ 27 | ``` 28 | 29 | ## Testing 30 | 31 | You can use the `test_binary.py` script to easily run all tests on a local binary. Example usage: 32 | 33 | ```bash 34 | python3 test_binary.py --program sqlite3 35 | python3 test_binary.py --program mysql --extra "-u root" 36 | python3 test_binary.py --program psql --extra "-d postgres" 37 | python3 test_binary.py --program duckdb 38 | ``` 39 | 40 | ## Systems known to be compliant 41 | 42 | * [Compatibility Matrix](https://docs.google.com/spreadsheets/d/1uDqQeXAWH8N9U6YeY5GpRgDsZugFUrMuz5EpXUutsVs/edit?usp=sharing) 43 | 44 | * [PostgreSQL](https://www.postgresql.org) 45 | * [Umbra](https://umbra-db.com) 46 | * [Hyper](https://tableau.github.io/hyper-db/) 47 | 48 | ## Contribute 49 | We welcome contributions with additional test cases. To add a test case, add a `.sql` file in the `tests` directory and run the `stitch.sh` script. 50 | 51 | ```bash 52 | ./stitch.sh tests/**/*.sql > acid.sql 53 | ``` 54 | 55 | If you want to add compliance tests please cite the relevant sections of the SQL standard. 56 | 57 | ## Credits 58 | The project was started as part of the [Dagstuhl Seminar 23441 : Ensuring the Reliability and Robustness of Database Management Systems](https://www.dagstuhl.de/en/seminars/seminar-calendar/seminar-details/23441) 59 | -------------------------------------------------------------------------------- /acid.sql: -------------------------------------------------------------------------------- 1 | -- provide test results here 2 | with testresults as ( 3 | 4 | select 1 as test, result from ( 5 | -- tests/compliance/test008.sql 6 | -- check that || is actually the string concat operator... 7 | -- CD 9075-2:201?(E) 8 | -- 4.2.3.2 Operators that operate on character strings and return character strings 9 | 10 | -- result header 11 | select case when s = 'abcdef' then 'T' else 'F' end as result 12 | from ( 13 | 14 | -- the query itself 15 | values ('abc' || 'def') 16 | 17 | ) t(s) 18 | ) testcase(result) UNION ALL select 2 as test, result from ( 19 | -- tests/compliance/test014.sql 20 | -- check that precedence matches the standard precedence order 21 | -- associativity rules for arithmetic is defined in 6.27 22 | select case when ( 23 | -- * has higher precedence than binary + 24 | (1+2*3) = (1+(2*3)) and 25 | 26 | -- / has higher precedence than binary - 27 | (2-3/4) = (2-(3/4)) and 28 | 29 | -- Left Associativity of /* 30 | (2/3/3) = ((2/3)/3) and 31 | (2/3*3) = ((2/3)*3) and 32 | 33 | -- < > = <> has lower precedence than binary -/+* 34 | (1+2 < 2+2) = ((1+2) < (2+2)) and 35 | (1+2 <= 1+2) = ((1+2) <= (1+2)) and 36 | (2+2 > 1+2) = ((2+2) > (1+2)) and 37 | (2+2 >= 1+2) = ((2+2) >= (1+2)) and 38 | (2+2 <> 1+2) = ((2+2) <> (1+2)) and 39 | 40 | -- in between has lower precedence than binary,unary operator 41 | (2 between 2-1 and 2+1) and 42 | (2 + 3 in (3+2)) and 43 | 44 | -- OR has lower preceedence than the logical negation 45 | (not true or true) = ((not true) or true) 46 | ) then 'T' else 'F' end as result 47 | ) testcase(result) UNION ALL select 3 as test, result from ( 48 | -- tests/compliance/test015.sql 49 | -- check that conjunctions correctly handle NULL values 50 | -- 6.35 - Truth table for AND/OR/IS 51 | SELECT case when 52 | (TRUE AND TRUE) IS TRUE AND 53 | (TRUE AND FALSE) IS FALSE AND 54 | (TRUE AND NULL) IS NULL AND 55 | (FALSE AND TRUE) IS FALSE AND 56 | (FALSE AND FALSE) IS FALSE AND 57 | (FALSE AND NULL) IS FALSE AND 58 | (NULL AND TRUE) IS NULL AND 59 | (NULL AND FALSE) IS FALSE AND 60 | (NULL AND NULL) IS NULL AND 61 | 62 | (TRUE OR TRUE) IS TRUE AND 63 | (TRUE OR FALSE) IS TRUE AND 64 | (TRUE OR NULL) IS TRUE AND 65 | (FALSE OR TRUE) IS TRUE AND 66 | (FALSE OR FALSE) IS FALSE AND 67 | (FALSE OR NULL) IS NULL AND 68 | (NULL OR TRUE) IS TRUE AND 69 | (NULL OR FALSE) IS NULL AND 70 | (NULL OR NULL) IS NULL 71 | then 'T' else 'F' end as result 72 | FROM (VALUES (42)) AS t 73 | ) testcase(result) UNION ALL select 4 as test, result from ( 74 | -- tests/compliance/test016.sql 75 | -- check standard type casts 76 | -- CD 9075-2:201?(E) 77 | -- 4.1.2 Naming of predefined types 78 | SELECT 79 | CASE WHEN 80 | CAST(NULL AS CHARACTER) IS NULL 81 | AND CAST(NULL AS NUMERIC) IS NULL 82 | AND CAST(NULL AS DECIMAL) IS NULL 83 | AND CAST(NULL AS SMALLINT) IS NULL 84 | AND CAST(NULL AS INTEGER) IS NULL 85 | AND CAST(NULL AS INT) IS NULL 86 | AND CAST(NULL AS BIGINT) IS NULL 87 | AND CAST(NULL AS FLOAT) IS NULL 88 | AND CAST(NULL AS REAL) IS NULL 89 | AND CAST(NULL AS DOUBLE PRECISION) IS NULL 90 | AND CAST('T' AS BOOLEAN) <> CAST('F' AS BOOLEAN) 91 | THEN 'T' ELSE 'F' END AS result 92 | ) testcase(result) UNION ALL select 5 as test, result from ( 93 | -- tests/compliance/test017.sql 94 | -- check case insensitivity in identifiers 95 | SELECT CASE WHEN T.HeLlO=t.hello THEN 'T' ELSE 'F' END AS result 96 | FROM (VALUES (42)) AS t(hello) 97 | ) testcase(result) UNION ALL select 6 as test, result from ( 98 | -- tests/compliance/test018.sql 99 | -- check standard behaviour of between predicates 100 | -- CD 9075-2:201?(E) 101 | -- 8.3 , Syntax Rules 6) 102 | 103 | select case when ( 104 | 0 BETWEEN -1 AND 1 AND 105 | 0.99 BETWEEN 0 AND 1 AND 106 | 107 | 0 BETWEEN 0 AND 0 AND 108 | 1 BETWEEN 0 AND 1 AND 109 | 0 BETWEEN 0 AND 1 AND 110 | 111 | -0 BETWEEN -0 AND +0 AND 112 | -0.00 BETWEEN -0.00 AND +0.00 AND 113 | 114 | 1.00 BETWEEN 0 AND 1.00 AND 115 | NOT 1.01 BETWEEN 0 AND 1 AND 116 | 117 | 'a' BETWEEN 'a' AND 'b' AND 118 | 'ab' BETWEEN 'a' AND 'b' AND 119 | 'b' BETWEEN 'a' AND 'b' AND 120 | NOT 'bla' BETWEEN 'a' AND 'b' AND 121 | 122 | (NULL BETWEEN NULL AND NULL) IS NULL AND 123 | (NULL BETWEEN 0 AND NULL) IS NULL AND 124 | (0 BETWEEN 0 AND NULL) IS NULL AND 125 | (NULL BETWEEN 0 AND 1 ) IS NULL AND 126 | 127 | TRUE BETWEEN FALSE AND TRUE AND 128 | FALSE BETWEEN FALSE AND TRUE 129 | 130 | ) then 'T' else 'F' end as result from (values (1)) as t 131 | ) testcase(result) UNION ALL select 7 as test, result from ( 132 | -- tests/compliance/test019.sql 133 | -- check string-to-number casting 134 | 135 | -- Support for the cast is required by the SQL Standard (see the table in 136 | -- 6.13 , Syntax Rules 6). The actual semantics aren't clear 137 | -- though. We believe the most sane behaviour to parse the string as a numeric 138 | -- literal as defined by the SQL Standard (see grammar rule called 139 | -- in 5.3 ). 140 | 141 | SELECT CASE WHEN ( 142 | CAST('+0' AS NUMERIC(10,3)) = CAST(+0 AS NUMERIC(10,3)) AND 143 | CAST('-0' AS NUMERIC(10,3)) = CAST(-0 AS NUMERIC(10,3)) AND 144 | 145 | CAST(' 1' AS NUMERIC(10,3)) = CAST( 1 AS NUMERIC(10,3)) AND 146 | CAST(' 1.' AS NUMERIC(10,3)) = CAST( 1. AS NUMERIC(10,3)) AND 147 | CAST(' 1.2' AS NUMERIC(10,3)) = CAST( 1.2 AS NUMERIC(10,3)) AND 148 | CAST(' .2' AS NUMERIC(10,3)) = CAST( .2 AS NUMERIC(10,3)) AND 149 | 150 | CAST('+1' AS NUMERIC(10,3)) = CAST(+1 AS NUMERIC(10,3)) AND 151 | CAST('+1.' AS NUMERIC(10,3)) = CAST(+1. AS NUMERIC(10,3)) AND 152 | CAST('+1.2' AS NUMERIC(10,3)) = CAST(+1.2 AS NUMERIC(10,3)) AND 153 | CAST('+.2' AS NUMERIC(10,3)) = CAST( +.2 AS NUMERIC(10,3)) AND 154 | 155 | CAST('-1' AS NUMERIC(10,3)) = CAST(-1 AS NUMERIC(10,3)) AND 156 | CAST('-1.' AS NUMERIC(10,3)) = CAST(-1. AS NUMERIC(10,3)) AND 157 | CAST('-1.2' AS NUMERIC(10,3)) = CAST(-1.2 AS NUMERIC(10,3)) AND 158 | CAST('-.2' AS NUMERIC(10,3)) = CAST( -.2 AS NUMERIC(10,3)) AND 159 | 160 | CAST(' 1.2E3' AS NUMERIC(10,3)) = CAST( 1.2E3 AS NUMERIC(10,3)) AND 161 | CAST('+1.2E3' AS NUMERIC(10,3)) = CAST(+1.2E3 AS NUMERIC(10,3)) AND 162 | CAST('-1.2E3' AS NUMERIC(10,3)) = CAST(-1.2E3 AS NUMERIC(10,3)) AND 163 | 164 | CAST(' 1.2E+3' AS NUMERIC(10,3)) = CAST( 1.2E+3 AS NUMERIC(10,3)) AND 165 | CAST('+1.2E+3' AS NUMERIC(10,3)) = CAST(+1.2E+3 AS NUMERIC(10,3)) AND 166 | CAST('-1.2E+3' AS NUMERIC(10,3)) = CAST(-1.2E+3 AS NUMERIC(10,3)) AND 167 | 168 | CAST(' 1.2E-3' AS NUMERIC(10,3)) = CAST( 1.2E-3 AS NUMERIC(10,3)) AND 169 | CAST('+1.2E-3' AS NUMERIC(10,3)) = CAST(+1.2E-3 AS NUMERIC(10,3)) AND 170 | CAST('-1.2E-3' AS NUMERIC(10,3)) = CAST(-1.2E-3 AS NUMERIC(10,3)) 171 | ) THEN 'T' ELSE 'F' END 172 | FROM (VALUES (1)) something(x) 173 | ) testcase(result) UNION ALL select 8 as test, result from ( 174 | -- tests/compliance/test020.sql 175 | -- SQL standard compliant identifiers 176 | -- delimited identifiers are defined in the grammar as follows: 177 | -- ::= 178 | -- 179 | -- ::= 180 | -- ... 181 | -- ::= 182 | -- 183 | -- | 184 | -- ::= 185 | -- ""!! two consecutive double quote characters 186 | -- in other words, delimited identifiers are started/terminated with double quotes, and double quotes are escaped with two consecutive double quotes 187 | SELECT CASE WHEN "this is an ""escaped"" identifier"."""escaped"""=1 THEN 'T' ELSE 'F' END AS result 188 | FROM (VALUES (1)) AS "this is an ""escaped"" identifier"("""escaped""") 189 | ) testcase(result) UNION ALL select 9 as test, result from ( 190 | -- tests/compliance/test021.sql 191 | -- SQL standard compliant string escape 192 | -- string literals are defined in the grammar as follows: 193 | -- ::= 194 | -- [ ] 195 | -- [ ... ] 196 | -- [ { [ ... ] }... ] 197 | -- ::= 198 | -- 199 | -- | 200 | -- ::= 201 | -- 202 | -- in other words, string literals are started/terminated with quotes, and quotes are escaped with two consecutive quotes 203 | SELECT CASE WHEN LENGTH(x)=1 THEN 'T' ELSE 'F' END AS result 204 | FROM (VALUES ('''')) AS t(x) 205 | ) testcase(result) UNION ALL select 10 as test, result from ( 206 | -- tests/compliance/test022.sql 207 | -- CD 9075-2:201?(E) 208 | -- 8.5 209 | SELECT CASE WHEN (1=1 210 | -- Normal LIKE tests 211 | AND 'HELLO' LIKE 'HELLO' 212 | AND 'HELLO' LIKE 'HEL%O' 213 | AND 'HELLO' LIKE 'HE%%O' 214 | AND 'HELLO' LIKE 'H%' 215 | AND 'HELLO' LIKE 'H_LLO' 216 | AND 'HELLO' LIKE '_ELLO' 217 | AND 'HELLO' LIKE '_____' 218 | AND 'HELLO' LIKE '_____%' 219 | AND 'HELLO' LIKE '%_____%' 220 | AND 'HELLO' LIKE '%%%%%%%' 221 | AND 'HELLO' LIKE '%%%%%%%' 222 | AND '%' LIKE '%' 223 | AND '_' LIKE '_' 224 | 225 | -- Normal NOT LIKE tests 226 | AND 'HELLO' NOT LIKE 'HeLLO' 227 | AND 'HELLO' NOT LIKE 'HeL%O' 228 | AND 'HELLO' NOT LIKE 'He%%O' 229 | AND 'HELLO' NOT LIKE 'h%' 230 | AND 'HELLO' NOT LIKE 'h_LLO' 231 | AND 'HELLO' NOT LIKE '_eLLO' 232 | AND 'HELLO' NOT LIKE '______' 233 | AND 'HELLO' NOT LIKE '______%' 234 | AND 'HELLO' NOT LIKE '%______%' 235 | AND 'HELLO' NOT LIKE 'h%%%%%%%' 236 | 237 | -- Test the ESCAPE clause 238 | AND '100%' LIKE '100b%' ESCAPE 'b' 239 | AND '1000' NOT LIKE '100b%' ESCAPE 'b' 240 | AND '100_' LIKE '100b_' ESCAPE 'b' 241 | AND '1000' NOT LIKE '100b_' ESCAPE 'b' 242 | AND '____' LIKE 'b_b_b_b_' ESCAPE 'b' 243 | AND '_--_' NOT LIKE 'b_b_b_b_' ESCAPE 'b' 244 | AND '_%%_' LIKE 'b_b%b%b_' ESCAPE 'b' 245 | AND '_--_' NOT LIKE 'b_b%b%b_' ESCAPE 'b' 246 | AND 'b' LIKE 'bb' ESCAPE 'b' 247 | AND 'bbb' LIKE 'bbbbbb' ESCAPE 'b' 248 | AND 'bbbH' LIKE 'bbbbbbH' ESCAPE 'b' 249 | 250 | -- NULL semantics 251 | AND ('HELLO' LIKE NULL) IS NULL 252 | AND (NULL LIKE NULL) IS NULL 253 | AND (NULL LIKE 'HELLO') IS NULL 254 | AND ('HELLO' LIKE 'HELLO' ESCAPE NULL) IS NULL 255 | AND (NULL LIKE NULL ESCAPE NULL) IS NULL 256 | AND (NULL LIKE 'HELLO' ESCAPE NULL) IS NULL 257 | AND (NULL LIKE NULL ESCAPE NULL) IS NULL 258 | 259 | ) THEN 'T' ELSE 'F' END 260 | FROM (VALUES (1)) t(x) 261 | ) testcase(result) UNION ALL select 11 as test, result from ( 262 | -- tests/compliance/test023.sql 263 | -- CD 9075-2:201?(E) 264 | -- 8.15 265 | -- 4.1 Data types 266 | -- 4.5.1 Introduction to Boolean types 267 | 268 | 269 | SELECT CASE WHEN 270 | NULL IS UNKNOWN 271 | AND (NULL IS UNKNOWN) IS NOT UNKNOWN 272 | AND (NULL = 42) IS UNKNOWN 273 | AND ((NULL AND FALSE) IS NOT DISTINCT FROM FALSE) 274 | AND ((NULL OR TRUE) IS NOT DISTINCT FROM TRUE) 275 | AND (NULL IS NULL) 276 | AND ((NULL IS TRUE) IS NOT UNKNOWN) 277 | AND ((NULL IS TRUE) IS NOT DISTINCT FROM FALSE) 278 | AND ((NULL IS FALSE) IS NOT UNKNOWN) 279 | AND ((NULL IS FALSE) IS NOT DISTINCT FROM FALSE) 280 | THEN 'T' 281 | ELSE 'F' 282 | END 283 | ) testcase(result) UNION ALL select 12 as test, result from ( 284 | -- tests/compliance/test024.sql 285 | -- Section 4.2.3.3 286 | SELECT CASE WHEN 287 | LENGTH(x)=5 AND 288 | POSITION ('l' IN x)=3 AND 289 | 'hello' = x AND 290 | NOT('hello' <> x) 291 | THEN 'T' ELSE 'F' END AS result 292 | FROM (VALUES ('hello')) AS t(x) 293 | ) testcase(result) UNION ALL select 13 as test, result from ( 294 | -- tests/compliance/test025.sql 295 | -- extract 296 | -- date/time/timestamp literals are defined in 5.3 297 | -- extract is defined in 6.28 298 | SELECT CASE WHEN 299 | EXTRACT(YEAR FROM date_col)=2000 AND 300 | EXTRACT(MONTH FROM date_col)=2 AND 301 | EXTRACT(DAY FROM date_col)=3 AND 302 | 303 | EXTRACT(YEAR FROM ts_col)=2000 AND 304 | EXTRACT(MONTH FROM ts_col)=2 AND 305 | EXTRACT(DAY FROM ts_col)=3 AND 306 | EXTRACT(HOUR FROM ts_col)=12 AND 307 | EXTRACT(MINUTE FROM ts_col)=23 AND 308 | EXTRACT(SECOND FROM ts_col)=45 AND 309 | 310 | EXTRACT(HOUR FROM time_col)=12 AND 311 | EXTRACT(MINUTE FROM time_col)=23 AND 312 | EXTRACT(SECOND FROM time_col)=45 313 | THEN 'T' 314 | ELSE 'F' 315 | END AS result 316 | FROM (VALUES ( 317 | DATE '2000-02-03', 318 | TIMESTAMP '2000-02-03 12:23:45', 319 | TIME '12:23:45' 320 | )) AS t(date_col, ts_col, time_col) 321 | ) testcase(result) UNION ALL select 14 as test, result from ( 322 | -- tests/compliance/test027.sql 323 | -- check math functions defined in the standard 324 | 325 | -- ISO 9075-2:2023(E) 326 | -- 6.31 327 | 328 | SELECT CASE WHEN ( 329 | abs( 0) = 0 AND 330 | abs(-1) = 1 AND 331 | abs(-1) = 1 AND 332 | 333 | mod( 2, 1) = 0 AND 334 | mod(-3, 1) = 0 AND 335 | mod(-3, 2) = -1 AND 336 | mod(-3, 3) = 0 AND 337 | mod(-3, 4) = -3 AND 338 | mod(-3, 5) = -3 AND 339 | 340 | ln(0.5) BETWEEN -0.69315 AND -0.69314 AND 341 | ln(1.0) = 0 AND 342 | ln(1.5) BETWEEN 0.40546 AND 0.40547 AND 343 | 344 | exp(-1) BETWEEN 0.36787 AND 0.36788 AND 345 | exp( 0) = 1 AND 346 | exp( 1) BETWEEN 2.71828 AND 2.71829 AND 347 | 348 | power( 0, 0) = 1 AND 349 | power(10, 0) = 1 AND 350 | power( 3, 1) = 3 AND 351 | power( 3, 2) = 9 AND 352 | power( 3, 3) = 27 AND 353 | 354 | sqrt( 2) BETWEEN 1.41421 AND 1.41422 AND 355 | sqrt( 4) = 2 AND 356 | sqrt( 9) = 3 AND 357 | sqrt( 16) = 4 AND 358 | sqrt( 1000000) = 1000 AND 359 | sqrt(10000000) BETWEEN 3162.27766 AND 3162.27767 AND 360 | 361 | floor(1.2) = 1 AND 362 | floor(1.8) = 1 AND 363 | 364 | ceil(1.2) = 2 AND 365 | ceil(1.8) = 2 AND 366 | 367 | log(2, 1) = 0 AND 368 | log(2, 2) = 1 AND 369 | log(3, 2) BETWEEN 0.63092 AND 0.63093 AND 370 | 371 | sin(-1.0 * acos(-1)) BETWEEN -0.000001 AND 0.000001 AND 372 | sin(-0.5 * acos(-1)) BETWEEN -1.000001 AND -0.999999 AND 373 | sin( 0 ) BETWEEN -0.000001 AND 0.000001 AND 374 | sin(+0.5 * acos(-1)) BETWEEN 0.999999 AND 1.000001 AND 375 | sin(+1.0 * acos(-1)) BETWEEN -0.000001 AND 0.000001 AND 376 | 377 | cos(-1.0 * acos(-1)) BETWEEN -1.000001 AND -0.999999 AND 378 | cos(-0.5 * acos(-1)) BETWEEN -0.000001 AND 0.000001 AND 379 | cos( 0 ) BETWEEN 0.999999 AND 1.000001 AND 380 | cos(+0.5 * acos(-1)) BETWEEN -0.000001 AND 0.000001 AND 381 | cos(+1.0 * acos(-1)) BETWEEN -1.000001 AND -0.999999 AND 382 | 383 | tan(-1.0 * acos(-1)) BETWEEN -0.000001 AND 0.000001 AND 384 | tan( 0 ) BETWEEN -0.000001 AND 0.000001 AND 385 | tan(+1.0 * acos(-1)) BETWEEN -0.000001 AND 0.000001 AND 386 | 387 | asin(-1.0) BETWEEN -1.570797 AND -1.570796 AND 388 | asin(-0.5) BETWEEN -0.523599 AND -0.523598 AND 389 | asin( 0.0) BETWEEN -0.000001 AND 0.000001 AND 390 | asin(+0.5) BETWEEN 0.523598 AND 0.523599 AND 391 | asin(+1.0) BETWEEN 1.570796 AND 1.570797 AND 392 | 393 | acos(-1.0) BETWEEN 3.141592 AND 3.141593 AND 394 | acos(-0.5) BETWEEN 2.094395 AND 2.094396 AND 395 | acos( 0.0) BETWEEN 1.570796 AND 1.570797 AND 396 | acos(+0.5) BETWEEN 1.047197 AND 1.047198 AND 397 | acos(+1.0) BETWEEN -0.000001 AND 0.000001 AND 398 | 399 | atan(-1.0) BETWEEN -0.785399 AND -0.785398 AND 400 | atan(-0.5) BETWEEN -0.463648 AND -0.463647 AND 401 | atan( 0.0) BETWEEN -0.000001 AND 0.000001 AND 402 | atan(+0.5) BETWEEN 0.463647 AND 0.463648 AND 403 | atan(+1.0) BETWEEN 0.785398 AND 0.785399 404 | ) THEN 'T' ELSE 'F' END 405 | FROM (VALUES (1)) something(x) 406 | ) testcase(result) UNION ALL select 15 as test, result from ( 407 | -- tests/convention/test001.sql 408 | -- check that the engine handles existential queries in disjunctions 409 | 410 | -- result header 411 | select case when queryresult = 11 then 'T' else 'F' end as result 412 | from ( 413 | 414 | -- the query itself 415 | select sum(x) as queryresult 416 | from (values(1),(2),(4),(8),(NULL)) s(x) 417 | where exists(select * from (values(2),(8)) t(y) where x=y) or (x<3) 418 | 419 | ) test 420 | ) testcase(result) UNION ALL select 16 as test, result from ( 421 | -- tests/convention/test002.sql 422 | -- test that casting to integer rounds and does not truncate 423 | 424 | SELECT case when CAST (4.8 AS INTEGER) = 5 AND CAST(4.2 AS INTEGER) = 4 then 'T' else 'F' end as result 425 | ) testcase(result) UNION ALL select 17 as test, result from ( 426 | -- tests/convention/test003.sql 427 | -- check that that quantified expressions return NULL values as needed 428 | 429 | -- result header 430 | select case when (r1=5) and (r2=40) then 'T' else 'F' end as result 431 | from ( 432 | 433 | -- the query itself 434 | select sum(case when m then i else 0 end) as r1, sum(case when m is null then i else 0 end) r2 435 | from ( 436 | select i, x=some(select a from (values(1,1),(2,2),(3,3),(4,4),(NULL,5)) t(a,b) where b CAST('123 ' AS varchar(10)) then 'T' else 'F' end AS result 537 | ) testcase(result) UNION ALL select 24 as test, result from ( 538 | -- tests/convention/test011.sql 539 | SELECT case when AVG(x)>0 then 'T' else 'F' end AS result 540 | FROM ( 541 | SELECT CAST(9223372036854775807 AS BIGINT) AS x 542 | UNION ALL 543 | SELECT CAST(9223372036854775807 AS BIGINT) 544 | ) AS t 545 | ) testcase(result) UNION ALL select 25 as test, result from ( 546 | -- tests/convention/test012.sql 547 | -- check that aggregations are correctly extracted from a subquery 548 | SELECT case when (SELECT SUM(x))=42 then 'T' else 'F' end AS result 549 | FROM (VALUES (42)) AS t(x) 550 | ) testcase(result) UNION ALL select 26 as test, result from ( 551 | -- tests/convention/test013.sql 552 | -- check that recursive queries work 553 | 554 | -- result header 555 | select case when (state='924875136138624795765391842546713928812469357397582614651238479489157263273946581') then 'T' else 'F' end as result 556 | from ( 557 | 558 | 559 | -- the query itself 560 | with recursive 561 | digits(value,ch) as (values(1,'1'),(2,'2'),(3,'3'),(4,'4'),(5,'5'),(6,'6'),(7,'7'),(8,'8'),(9,'9')), 562 | sudoku(state, next) as 563 | (select state, position(' ' in state) as next 564 | from (select '9 1 6 62 79 5 1 54 2 81 6935739 5826 46 7 915 32 3 46 ') s(state) 565 | union all 566 | select state, position(' ' in state) as next 567 | from (select substring(state from 1 for next-1) || try || substring(state from next+1) as state 568 | from sudoku, (select ch as try from digits) g 569 | where next > 0 and 570 | not exists(select 1 from (select value as pos from digits) s 571 | where try = substring(state from cast(floor((next-1)/9) as integer)*9+pos for 1) 572 | or try = substring(state from mod((next-1),9)+9*pos-8 for 1) 573 | or try = substring(state from mod(cast(floor((next-1)/3) as integer),3)*3+cast(floor((next-1)/27) as integer)*27+pos+cast(floor((pos-1)/3) as integer)*6 for 1)) 574 | ) c) 575 | select state from sudoku where next=0 576 | 577 | ) test 578 | ) testcase(result) UNION ALL select 27 as test, result from ( 579 | -- tests/convention/test026.sql 580 | -- Test that an alias from the select clause can be used in the order by clause 581 | -- Should be standard compliant (CD 9075-2:201?(E) 7.16 ), 582 | -- but I cannot find the section that says so explicitly. 583 | select case when (true 584 | and (select a as b from (values (1)) t(a) order by b) = 1 585 | ) then 'T' else 'F' end from (values (1)) AS t 586 | ) testcase(result) UNION ALL select index as test, 'T' as result from generate_series(28,260) s(index) 587 | ) 588 | -- render the result 589 | select case when state = 1048575 then image else 'XXXXXXXXXXXXXXXXXXXX' end as output from (values 590 | (0, '+-----------------+'), 591 | (1, '|......#####......|'), 592 | (2, '|....##.....##....|'), 593 | (3, '|...#.........#...|'), 594 | (4, '|..#..()...()..#..|'), 595 | (5, '|..#.....o.....#..|'), 596 | (6, '|.#.............#.|'), 597 | (7, '|..#..\...../..#..|'), 598 | (8, '|..#...-----...#..|'), 599 | (9, '|...#.........#...|'), 600 | (10,'|....##.....##....|'), 601 | (11,'|......#####......|'), 602 | (12,'+-----------------+') 603 | ) image(line, image) left outer join ( 604 | select line, sum(cast(power(2,ofs) as integer)) as state 605 | from (select line, test-1-20*line as ofs, test, result 606 | from (select cast(floor((test-1)/20) as integer) as line, test, result from testresults where result = 'T') s 607 | ) s group by line) s 608 | on image.line=s.line order by image.line; 609 | -------------------------------------------------------------------------------- /logo.svg: -------------------------------------------------------------------------------- 1 | 2 | 3 | 4 | 5 | 6 | 7 | 8 | 9 | 10 | 11 | 12 | 13 | 14 | 15 | 16 | 17 | 18 | 19 | 20 | 21 | 22 | 23 | 24 | 25 | 26 | 27 | 28 | 29 | 30 | 31 | 32 | 33 | 34 | 35 | 36 | 37 | 38 | 39 | 40 | 41 | 42 | 43 | 44 | 45 | 46 | 47 | 48 | 49 | 50 | 51 | 52 | 53 | 54 | 55 | 56 | 57 | 58 | 59 | 60 | 61 | 62 | 63 | 64 | 65 | 66 | 67 | 68 | 69 | -------------------------------------------------------------------------------- /renderer.sql: -------------------------------------------------------------------------------- 1 | -- provide test results here 2 | with testresults as ( 3 | -- START TEST CASES 4 | select index as test, 'T' as result from generate_series(1,260) s(index) 5 | -- END TEST CASES 6 | ) 7 | -- render the result 8 | select case when state = 1048575 then image else 'XXXXXXXXXXXXXXXXXXXX' end as output from (values 9 | (0, '+-----------------+'), 10 | (1, '|......#####......|'), 11 | (2, '|....##.....##....|'), 12 | (3, '|...#.........#...|'), 13 | (4, '|..#..()...()..#..|'), 14 | (5, '|..#.....o.....#..|'), 15 | (6, '|.#.............#.|'), 16 | (7, '|..#..\...../..#..|'), 17 | (8, '|..#...-----...#..|'), 18 | (9, '|...#.........#...|'), 19 | (10,'|....##.....##....|'), 20 | (11,'|......#####......|'), 21 | (12,'+-----------------+') 22 | ) image(line, image) left outer join ( 23 | select line, sum(cast(power(2,ofs) as integer)) as state 24 | from (select line, test-1-20*line as ofs, test, result 25 | from (select cast(floor((test-1)/20) as integer) as line, test, result from testresults where result = 'T') s 26 | ) s group by line) s 27 | on image.line=s.line order by image.line; 28 | 29 | -------------------------------------------------------------------------------- /stitch.sh: -------------------------------------------------------------------------------- 1 | #!/bin/bash 2 | 3 | USAGE=`cat <... 7 | 8 | Arguments: 9 | ... 10 | The tests to stich together. These should be SQL files that adhere to 11 | the following format 12 | 13 | [TODO] 14 | 15 | Options: 16 | -r, --render-template 17 | 18 | -h, --help 19 | Print this and exit. 20 | END` 21 | 22 | usage() { printf "$USAGE\n"; exit 1; } 23 | 24 | ABORT='/!\ %s' 25 | 26 | abort() { printf "$ABORT\n" "$1" >&2; usage; } 27 | 28 | PROJECT_DIR="$( cd -- "$( dirname -- "${BASH_SOURCE[0]}" )" &> /dev/null && pwd )" 29 | RENDER_TEMPLATE_FILE="$PROJECT_DIR/renderer.sql" 30 | 31 | TEST_FILES=() 32 | 33 | while [[ $# -gt 0 ]]; do 34 | case $1 in 35 | -r|--render-template) 36 | RENDER_TEMPLATE_FILE="$2" 37 | shift 2 38 | ;; 39 | -h|--help) 40 | usage 41 | ;; 42 | -*|--*) 43 | abort "Unknown option: $1" 44 | ;; 45 | *) 46 | TEST_FILES+=("$1") 47 | shift 48 | ;; 49 | esac 50 | done 51 | 52 | N_TESTS="${#TEST_FILES[@]}" 53 | if [[ $N_TESTS -ge 260 ]]; then 54 | abort "too many test cases (max 260 allowed)" 55 | fi 56 | 57 | function uglify() { 58 | sed -E "s/--.*//;s/;//" "${1:-/dev/stdin}" | tr '\n\n' '\n' 59 | } 60 | 61 | RENDER_TEMPLATE="$(< $RENDER_TEMPLATE_FILE)" 62 | RENDER_TEMPLATE_HEAD="${RENDER_TEMPLATE%-- START TEST CASES*}" 63 | RENDER_TEMPLATE_TAIL="${RENDER_TEMPLATE#*-- END TEST CASES}" 64 | 65 | echo "$RENDER_TEMPLATE_HEAD" 66 | 67 | for (( i=0; i < N_TESTS; i++ )); do 68 | TEST_FILE="${TEST_FILES[$i]}" 69 | printf 'select %d as test, result from (\n-- %s\n%s\n) testcase(result) UNION ALL ' "$((1+i))" "$TEST_FILE" "$(< "$TEST_FILE")" 70 | done 71 | 72 | printf "select index as test, 'T' as result from generate_series($((N_TESTS+1)),260) s(index) " 73 | 74 | echo "$RENDER_TEMPLATE_TAIL" 75 | -------------------------------------------------------------------------------- /test_binary.py: -------------------------------------------------------------------------------- 1 | import argparse 2 | import subprocess 3 | import os 4 | import re 5 | 6 | # Example usage: 7 | # python3 test_binary.py --program sqlite3 8 | # python3 test_binary.py --program mysql --extra "-u root" 9 | # python3 test_binary.py --program psql --extra "-d postgres" 10 | # python3 test_binary.py --program duckdb 11 | 12 | test_dir = 'sql' 13 | skip_tests = ['renderer.sql'] 14 | 15 | parser = argparse.ArgumentParser(description='Run all tests for a random binary.') 16 | parser.add_argument( 17 | '--program', 18 | dest='program', 19 | action='store', 20 | help='Program to test', 21 | required=True, 22 | ) 23 | parser.add_argument( 24 | '--extra', 25 | dest='extra', 26 | action='store', 27 | help='The extra arguments to pass to the binary', 28 | default='' 29 | ) 30 | parser.add_argument( 31 | '--test', 32 | dest='test', 33 | action='store', 34 | help='Specifies which test to run (default: all)', 35 | default='' 36 | ) 37 | parser.add_argument( 38 | '--verbose', 39 | dest='verbose', 40 | action='store_true', 41 | help='Verbose (print failures)', 42 | default=False 43 | ) 44 | args = parser.parse_args() 45 | 46 | 47 | command = [args.program] 48 | if len(args.extra) > 0: 49 | command += args.extra.strip().split(' ') 50 | 51 | def run_test(file_name): 52 | input_data = open(file_name).read() 53 | input_data = re.sub('--[^\n]+', '', input_data) + ';' 54 | res = subprocess.run(command, input=input_data.encode('utf8'), stdout=subprocess.PIPE, stderr=subprocess.PIPE) 55 | stdout = res.stdout.decode('utf8').strip() 56 | stderr = res.stderr.decode('utf8').strip() 57 | if res.returncode != 0: 58 | if args.verbose: 59 | print(file_name) 60 | print(stdout) 61 | print(stderr) 62 | result = 'Error' 63 | elif 'T' in stdout: 64 | result = 'Success' 65 | elif 'F' in stdout: 66 | result = 'Fail' 67 | else: 68 | print(file_name) 69 | print(stdout) 70 | print(stderr) 71 | raise Exception('Found neither T nor F in result') 72 | print(file_name + ' - ' + result) 73 | 74 | file_list = os.listdir(test_dir) 75 | file_list = sorted(file_list) 76 | for f in file_list: 77 | if f in skip_tests: 78 | continue 79 | if len(args.test) > 0 and args.test not in f: 80 | continue 81 | test_name = os.path.join(test_dir, f) 82 | run_test(test_name) 83 | -------------------------------------------------------------------------------- /tests/compliance/test008.sql: -------------------------------------------------------------------------------- 1 | -- check that || is actually the string concat operator... 2 | -- CD 9075-2:201?(E) 3 | -- 4.2.3.2 Operators that operate on character strings and return character strings 4 | 5 | -- result header 6 | select case when s = 'abcdef' then 'T' else 'F' end as result 7 | from ( 8 | 9 | -- the query itself 10 | values ('abc' || 'def') 11 | 12 | ) t(s) 13 | -------------------------------------------------------------------------------- /tests/compliance/test014.sql: -------------------------------------------------------------------------------- 1 | -- check that precedence matches the standard precedence order 2 | -- associativity rules for arithmetic is defined in 6.27 3 | select case when ( 4 | -- * has higher precedence than binary + 5 | (1+2*3) = (1+(2*3)) and 6 | 7 | -- / has higher precedence than binary - 8 | (2-3/4) = (2-(3/4)) and 9 | 10 | -- Left Associativity of /* 11 | (2/3/3) = ((2/3)/3) and 12 | (2/3*3) = ((2/3)*3) and 13 | 14 | -- < > = <> has lower precedence than binary -/+* 15 | (1+2 < 2+2) = ((1+2) < (2+2)) and 16 | (1+2 <= 1+2) = ((1+2) <= (1+2)) and 17 | (2+2 > 1+2) = ((2+2) > (1+2)) and 18 | (2+2 >= 1+2) = ((2+2) >= (1+2)) and 19 | (2+2 <> 1+2) = ((2+2) <> (1+2)) and 20 | 21 | -- in between has lower precedence than binary,unary operator 22 | (2 between 2-1 and 2+1) and 23 | (2 + 3 in (3+2)) and 24 | 25 | -- OR has lower preceedence than the logical negation 26 | (not true or true) = ((not true) or true) 27 | ) then 'T' else 'F' end as result 28 | -------------------------------------------------------------------------------- /tests/compliance/test015.sql: -------------------------------------------------------------------------------- 1 | -- check that conjunctions correctly handle NULL values 2 | -- 6.35 - Truth table for AND/OR/IS 3 | SELECT case when 4 | (TRUE AND TRUE) IS TRUE AND 5 | (TRUE AND FALSE) IS FALSE AND 6 | (TRUE AND NULL) IS NULL AND 7 | (FALSE AND TRUE) IS FALSE AND 8 | (FALSE AND FALSE) IS FALSE AND 9 | (FALSE AND NULL) IS FALSE AND 10 | (NULL AND TRUE) IS NULL AND 11 | (NULL AND FALSE) IS FALSE AND 12 | (NULL AND NULL) IS NULL AND 13 | 14 | (TRUE OR TRUE) IS TRUE AND 15 | (TRUE OR FALSE) IS TRUE AND 16 | (TRUE OR NULL) IS TRUE AND 17 | (FALSE OR TRUE) IS TRUE AND 18 | (FALSE OR FALSE) IS FALSE AND 19 | (FALSE OR NULL) IS NULL AND 20 | (NULL OR TRUE) IS TRUE AND 21 | (NULL OR FALSE) IS NULL AND 22 | (NULL OR NULL) IS NULL 23 | then 'T' else 'F' end as result 24 | FROM (VALUES (42)) AS t 25 | -------------------------------------------------------------------------------- /tests/compliance/test016.sql: -------------------------------------------------------------------------------- 1 | -- check standard type casts 2 | -- CD 9075-2:201?(E) 3 | -- 4.1.2 Naming of predefined types 4 | SELECT 5 | CASE WHEN 6 | CAST(NULL AS CHARACTER) IS NULL 7 | AND CAST(NULL AS NUMERIC(10,2)) IS NULL 8 | AND CAST(NULL AS DECIMAL(10,2)) IS NULL 9 | AND CAST(NULL AS SMALLINT) IS NULL 10 | AND CAST(NULL AS INTEGER) IS NULL 11 | AND CAST(NULL AS INT) IS NULL 12 | AND CAST(NULL AS BIGINT) IS NULL 13 | AND CAST(NULL AS FLOAT) IS NULL 14 | AND CAST(NULL AS REAL) IS NULL 15 | AND CAST(NULL AS DOUBLE PRECISION) IS NULL 16 | AND CAST('T' AS BOOLEAN) <> CAST('F' AS BOOLEAN) 17 | THEN 'T' ELSE 'F' END AS result 18 | -------------------------------------------------------------------------------- /tests/compliance/test017.sql: -------------------------------------------------------------------------------- 1 | -- check case insensitivity in identifiers 2 | SELECT CASE WHEN T.HeLlO=t.hello THEN 'T' ELSE 'F' END AS result 3 | FROM (VALUES (42)) AS t(hello) 4 | -------------------------------------------------------------------------------- /tests/compliance/test018.sql: -------------------------------------------------------------------------------- 1 | -- check standard behaviour of between predicates 2 | -- CD 9075-2:201?(E) 3 | -- 8.3 , Syntax Rules 6) 4 | 5 | select case when ( 6 | 0 BETWEEN -1 AND 1 AND 7 | 0.99 BETWEEN 0 AND 1 AND 8 | 9 | 0 BETWEEN 0 AND 0 AND 10 | 1 BETWEEN 0 AND 1 AND 11 | 0 BETWEEN 0 AND 1 AND 12 | 13 | -0 BETWEEN -0 AND +0 AND 14 | -0.00 BETWEEN -0.00 AND +0.00 AND 15 | 16 | 1.00 BETWEEN 0 AND 1.00 AND 17 | NOT 1.01 BETWEEN 0 AND 1 AND 18 | 19 | 'a' BETWEEN 'a' AND 'b' AND 20 | 'ab' BETWEEN 'a' AND 'b' AND 21 | 'b' BETWEEN 'a' AND 'b' AND 22 | NOT 'bla' BETWEEN 'a' AND 'b' AND 23 | 24 | (NULL BETWEEN NULL AND NULL) IS NULL AND 25 | (NULL BETWEEN 0 AND NULL) IS NULL AND 26 | (0 BETWEEN 0 AND NULL) IS NULL AND 27 | (NULL BETWEEN 0 AND 1 ) IS NULL AND 28 | 29 | TRUE BETWEEN FALSE AND TRUE AND 30 | FALSE BETWEEN FALSE AND TRUE 31 | 32 | ) then 'T' else 'F' end as result from (values (1)) as t 33 | -------------------------------------------------------------------------------- /tests/compliance/test019.sql: -------------------------------------------------------------------------------- 1 | -- check string-to-number casting 2 | 3 | -- Support for the cast is required by the SQL Standard (see the table in 4 | -- 6.13 , Syntax Rules 6). The actual semantics aren't clear 5 | -- though. We believe the most sane behaviour to parse the string as a numeric 6 | -- literal as defined by the SQL Standard (see grammar rule called 7 | -- in 5.3 ). 8 | 9 | SELECT CASE WHEN ( 10 | CAST('+0' AS NUMERIC(10,3)) = CAST(+0 AS NUMERIC(10,3)) AND 11 | CAST('-0' AS NUMERIC(10,3)) = CAST(-0 AS NUMERIC(10,3)) AND 12 | 13 | CAST(' 1' AS NUMERIC(10,3)) = CAST( 1 AS NUMERIC(10,3)) AND 14 | CAST(' 1.' AS NUMERIC(10,3)) = CAST( 1. AS NUMERIC(10,3)) AND 15 | CAST(' 1.2' AS NUMERIC(10,3)) = CAST( 1.2 AS NUMERIC(10,3)) AND 16 | CAST(' .2' AS NUMERIC(10,3)) = CAST( .2 AS NUMERIC(10,3)) AND 17 | 18 | CAST('+1' AS NUMERIC(10,3)) = CAST(+1 AS NUMERIC(10,3)) AND 19 | CAST('+1.' AS NUMERIC(10,3)) = CAST(+1. AS NUMERIC(10,3)) AND 20 | CAST('+1.2' AS NUMERIC(10,3)) = CAST(+1.2 AS NUMERIC(10,3)) AND 21 | CAST('+.2' AS NUMERIC(10,3)) = CAST( +.2 AS NUMERIC(10,3)) AND 22 | 23 | CAST('-1' AS NUMERIC(10,3)) = CAST(-1 AS NUMERIC(10,3)) AND 24 | CAST('-1.' AS NUMERIC(10,3)) = CAST(-1. AS NUMERIC(10,3)) AND 25 | CAST('-1.2' AS NUMERIC(10,3)) = CAST(-1.2 AS NUMERIC(10,3)) AND 26 | CAST('-.2' AS NUMERIC(10,3)) = CAST( -.2 AS NUMERIC(10,3)) AND 27 | 28 | CAST(' 1.2E3' AS NUMERIC(10,3)) = CAST( 1.2E3 AS NUMERIC(10,3)) AND 29 | CAST('+1.2E3' AS NUMERIC(10,3)) = CAST(+1.2E3 AS NUMERIC(10,3)) AND 30 | CAST('-1.2E3' AS NUMERIC(10,3)) = CAST(-1.2E3 AS NUMERIC(10,3)) AND 31 | 32 | CAST(' 1.2E+3' AS NUMERIC(10,3)) = CAST( 1.2E+3 AS NUMERIC(10,3)) AND 33 | CAST('+1.2E+3' AS NUMERIC(10,3)) = CAST(+1.2E+3 AS NUMERIC(10,3)) AND 34 | CAST('-1.2E+3' AS NUMERIC(10,3)) = CAST(-1.2E+3 AS NUMERIC(10,3)) AND 35 | 36 | CAST(' 1.2E-3' AS NUMERIC(10,3)) = CAST( 1.2E-3 AS NUMERIC(10,3)) AND 37 | CAST('+1.2E-3' AS NUMERIC(10,3)) = CAST(+1.2E-3 AS NUMERIC(10,3)) AND 38 | CAST('-1.2E-3' AS NUMERIC(10,3)) = CAST(-1.2E-3 AS NUMERIC(10,3)) 39 | ) THEN 'T' ELSE 'F' END 40 | FROM (VALUES (1)) something(x) 41 | -------------------------------------------------------------------------------- /tests/compliance/test020.sql: -------------------------------------------------------------------------------- 1 | -- SQL standard compliant identifiers 2 | -- delimited identifiers are defined in the grammar as follows: 3 | -- ::= 4 | -- 5 | -- ::= 6 | -- ... 7 | -- ::= 8 | -- 9 | -- | 10 | -- ::= 11 | -- ""!! two consecutive double quote characters 12 | -- in other words, delimited identifiers are started/terminated with double quotes, and double quotes are escaped with two consecutive double quotes 13 | SELECT CASE WHEN "this is an ""escaped"" identifier"."""escaped"""=1 THEN 'T' ELSE 'F' END AS result 14 | FROM (VALUES (1)) AS "this is an ""escaped"" identifier"("""escaped""") 15 | -------------------------------------------------------------------------------- /tests/compliance/test021.sql: -------------------------------------------------------------------------------- 1 | -- SQL standard compliant string escape 2 | -- string literals are defined in the grammar as follows: 3 | -- ::= 4 | -- [ ] 5 | -- [ ... ] 6 | -- [ { [ ... ] }... ] 7 | -- ::= 8 | -- 9 | -- | 10 | -- ::= 11 | -- 12 | -- in other words, string literals are started/terminated with quotes, and quotes are escaped with two consecutive quotes 13 | SELECT CASE WHEN LENGTH(x)=1 THEN 'T' ELSE 'F' END AS result 14 | FROM (VALUES ('''')) AS t(x) 15 | -------------------------------------------------------------------------------- /tests/compliance/test022.sql: -------------------------------------------------------------------------------- 1 | -- CD 9075-2:201?(E) 2 | -- 8.5 3 | SELECT CASE WHEN (1=1 4 | -- Normal LIKE tests 5 | AND 'HELLO' LIKE 'HELLO' 6 | AND 'HELLO' LIKE 'HEL%O' 7 | AND 'HELLO' LIKE 'HE%%O' 8 | AND 'HELLO' LIKE 'H%' 9 | AND 'HELLO' LIKE 'H_LLO' 10 | AND 'HELLO' LIKE '_ELLO' 11 | AND 'HELLO' LIKE '_____' 12 | AND 'HELLO' LIKE '_____%' 13 | AND 'HELLO' LIKE '%_____%' 14 | AND 'HELLO' LIKE '%%%%%%%' 15 | AND 'HELLO' LIKE '%%%%%%%' 16 | AND '%' LIKE '%' 17 | AND '_' LIKE '_' 18 | 19 | -- Normal NOT LIKE tests 20 | AND 'HELLO' NOT LIKE 'HeLLO' 21 | AND 'HELLO' NOT LIKE 'HeL%O' 22 | AND 'HELLO' NOT LIKE 'He%%O' 23 | AND 'HELLO' NOT LIKE 'h%' 24 | AND 'HELLO' NOT LIKE 'h_LLO' 25 | AND 'HELLO' NOT LIKE '_eLLO' 26 | AND 'HELLO' NOT LIKE '______' 27 | AND 'HELLO' NOT LIKE '______%' 28 | AND 'HELLO' NOT LIKE '%______%' 29 | AND 'HELLO' NOT LIKE 'h%%%%%%%' 30 | 31 | -- Test the ESCAPE clause 32 | AND '100%' LIKE '100b%' ESCAPE 'b' 33 | AND '1000' NOT LIKE '100b%' ESCAPE 'b' 34 | AND '100_' LIKE '100b_' ESCAPE 'b' 35 | AND '1000' NOT LIKE '100b_' ESCAPE 'b' 36 | AND '____' LIKE 'b_b_b_b_' ESCAPE 'b' 37 | AND '_--_' NOT LIKE 'b_b_b_b_' ESCAPE 'b' 38 | AND '_%%_' LIKE 'b_b%b%b_' ESCAPE 'b' 39 | AND '_--_' NOT LIKE 'b_b%b%b_' ESCAPE 'b' 40 | AND 'b' LIKE 'bb' ESCAPE 'b' 41 | AND 'bbb' LIKE 'bbbbbb' ESCAPE 'b' 42 | AND 'bbbH' LIKE 'bbbbbbH' ESCAPE 'b' 43 | 44 | -- NULL semantics 45 | AND ('HELLO' LIKE NULL) IS NULL 46 | AND (NULL LIKE NULL) IS NULL 47 | AND (NULL LIKE 'HELLO') IS NULL 48 | AND ('HELLO' LIKE 'HELLO' ESCAPE NULL) IS NULL 49 | AND (NULL LIKE NULL ESCAPE NULL) IS NULL 50 | AND (NULL LIKE 'HELLO' ESCAPE NULL) IS NULL 51 | AND (NULL LIKE NULL ESCAPE NULL) IS NULL 52 | 53 | ) THEN 'T' ELSE 'F' END 54 | FROM (VALUES (1)) t(x) 55 | -------------------------------------------------------------------------------- /tests/compliance/test023.sql: -------------------------------------------------------------------------------- 1 | -- CD 9075-2:201?(E) 2 | -- 8.15 3 | -- 4.1 Data types 4 | -- 4.5.1 Introduction to Boolean types 5 | 6 | 7 | SELECT CASE WHEN 8 | NULL IS UNKNOWN 9 | AND (NULL IS UNKNOWN) IS NOT UNKNOWN 10 | AND (NULL = 42) IS UNKNOWN 11 | AND ((NULL AND FALSE) IS NOT DISTINCT FROM FALSE) 12 | AND ((NULL OR TRUE) IS NOT DISTINCT FROM TRUE) 13 | AND (NULL IS NULL) 14 | AND ((NULL IS TRUE) IS NOT UNKNOWN) 15 | AND ((NULL IS TRUE) IS NOT DISTINCT FROM FALSE) 16 | AND ((NULL IS FALSE) IS NOT UNKNOWN) 17 | AND ((NULL IS FALSE) IS NOT DISTINCT FROM FALSE) 18 | THEN 'T' 19 | ELSE 'F' 20 | END 21 | -------------------------------------------------------------------------------- /tests/compliance/test024.sql: -------------------------------------------------------------------------------- 1 | -- Section 4.2.3.3 2 | SELECT CASE WHEN 3 | LENGTH(x)=5 AND 4 | POSITION ('l' IN x)=3 AND 5 | 'hello' = x AND 6 | NOT('hello' <> x) 7 | THEN 'T' ELSE 'F' END AS result 8 | FROM (VALUES ('hello')) AS t(x) -------------------------------------------------------------------------------- /tests/compliance/test025.sql: -------------------------------------------------------------------------------- 1 | -- extract 2 | -- date/time/timestamp literals are defined in 5.3 3 | -- extract is defined in 6.28 4 | SELECT CASE WHEN 5 | EXTRACT(YEAR FROM date_col)=2000 AND 6 | EXTRACT(MONTH FROM date_col)=2 AND 7 | EXTRACT(DAY FROM date_col)=3 AND 8 | 9 | EXTRACT(YEAR FROM ts_col)=2000 AND 10 | EXTRACT(MONTH FROM ts_col)=2 AND 11 | EXTRACT(DAY FROM ts_col)=3 AND 12 | EXTRACT(HOUR FROM ts_col)=12 AND 13 | EXTRACT(MINUTE FROM ts_col)=23 AND 14 | EXTRACT(SECOND FROM ts_col)=45 AND 15 | 16 | EXTRACT(HOUR FROM time_col)=12 AND 17 | EXTRACT(MINUTE FROM time_col)=23 AND 18 | EXTRACT(SECOND FROM time_col)=45 19 | THEN 'T' 20 | ELSE 'F' 21 | END AS result 22 | FROM (VALUES ( 23 | DATE '2000-02-03', 24 | TIMESTAMP '2000-02-03 12:23:45', 25 | TIME '12:23:45' 26 | )) AS t(date_col, ts_col, time_col) 27 | -------------------------------------------------------------------------------- /tests/compliance/test027.sql: -------------------------------------------------------------------------------- 1 | -- check math functions defined in the standard 2 | 3 | -- ISO 9075-2:2023(E) 4 | -- 6.31 5 | 6 | SELECT CASE WHEN ( 7 | abs( 0) = 0 AND 8 | abs(-1) = 1 AND 9 | abs(-1) = 1 AND 10 | 11 | mod( 2, 1) = 0 AND 12 | mod(-3, 1) = 0 AND 13 | mod(-3, 2) = -1 AND 14 | mod(-3, 3) = 0 AND 15 | mod(-3, 4) = -3 AND 16 | mod(-3, 5) = -3 AND 17 | 18 | ln(0.5) BETWEEN -0.69315 AND -0.69314 AND 19 | ln(1.0) = 0 AND 20 | ln(1.5) BETWEEN 0.40546 AND 0.40547 AND 21 | 22 | exp(-1) BETWEEN 0.36787 AND 0.36788 AND 23 | exp( 0) = 1 AND 24 | exp( 1) BETWEEN 2.71828 AND 2.71829 AND 25 | 26 | power( 0, 0) = 1 AND 27 | power(10, 0) = 1 AND 28 | power( 3, 1) = 3 AND 29 | power( 3, 2) = 9 AND 30 | power( 3, 3) = 27 AND 31 | 32 | sqrt( 2) BETWEEN 1.41421 AND 1.41422 AND 33 | sqrt( 4) = 2 AND 34 | sqrt( 9) = 3 AND 35 | sqrt( 16) = 4 AND 36 | sqrt( 1000000) = 1000 AND 37 | sqrt(10000000) BETWEEN 3162.27766 AND 3162.27767 AND 38 | 39 | floor(1.2) = 1 AND 40 | floor(1.8) = 1 AND 41 | 42 | ceil(1.2) = 2 AND 43 | ceil(1.8) = 2 AND 44 | 45 | log(2, 1) = 0 AND 46 | log(2, 2) = 1 AND 47 | log(3, 2) BETWEEN 0.63092 AND 0.63093 AND 48 | 49 | sin(-1.0 * acos(-1)) BETWEEN -0.000001 AND 0.000001 AND 50 | sin(-0.5 * acos(-1)) BETWEEN -1.000001 AND -0.999999 AND 51 | sin( 0 ) BETWEEN -0.000001 AND 0.000001 AND 52 | sin(+0.5 * acos(-1)) BETWEEN 0.999999 AND 1.000001 AND 53 | sin(+1.0 * acos(-1)) BETWEEN -0.000001 AND 0.000001 AND 54 | 55 | cos(-1.0 * acos(-1)) BETWEEN -1.000001 AND -0.999999 AND 56 | cos(-0.5 * acos(-1)) BETWEEN -0.000001 AND 0.000001 AND 57 | cos( 0 ) BETWEEN 0.999999 AND 1.000001 AND 58 | cos(+0.5 * acos(-1)) BETWEEN -0.000001 AND 0.000001 AND 59 | cos(+1.0 * acos(-1)) BETWEEN -1.000001 AND -0.999999 AND 60 | 61 | tan(-1.0 * acos(-1)) BETWEEN -0.000001 AND 0.000001 AND 62 | tan( 0 ) BETWEEN -0.000001 AND 0.000001 AND 63 | tan(+1.0 * acos(-1)) BETWEEN -0.000001 AND 0.000001 AND 64 | 65 | asin(-1.0) BETWEEN -1.570797 AND -1.570796 AND 66 | asin(-0.5) BETWEEN -0.523599 AND -0.523598 AND 67 | asin( 0.0) BETWEEN -0.000001 AND 0.000001 AND 68 | asin(+0.5) BETWEEN 0.523598 AND 0.523599 AND 69 | asin(+1.0) BETWEEN 1.570796 AND 1.570797 AND 70 | 71 | acos(-1.0) BETWEEN 3.141592 AND 3.141593 AND 72 | acos(-0.5) BETWEEN 2.094395 AND 2.094396 AND 73 | acos( 0.0) BETWEEN 1.570796 AND 1.570797 AND 74 | acos(+0.5) BETWEEN 1.047197 AND 1.047198 AND 75 | acos(+1.0) BETWEEN -0.000001 AND 0.000001 AND 76 | 77 | atan(-1.0) BETWEEN -0.785399 AND -0.785398 AND 78 | atan(-0.5) BETWEEN -0.463648 AND -0.463647 AND 79 | atan( 0.0) BETWEEN -0.000001 AND 0.000001 AND 80 | atan(+0.5) BETWEEN 0.463647 AND 0.463648 AND 81 | atan(+1.0) BETWEEN 0.785398 AND 0.785399 82 | ) THEN 'T' ELSE 'F' END 83 | FROM (VALUES (1)) something(x) 84 | -------------------------------------------------------------------------------- /tests/convention/test001.sql: -------------------------------------------------------------------------------- 1 | -- check that the engine handles existential queries in disjunctions 2 | 3 | -- result header 4 | select case when queryresult = 11 then 'T' else 'F' end as result 5 | from ( 6 | 7 | -- the query itself 8 | select sum(x) as queryresult 9 | from (values(1),(2),(4),(8),(NULL)) s(x) 10 | where exists(select * from (values(2),(8)) t(y) where x=y) or (x<3) 11 | 12 | ) test 13 | -------------------------------------------------------------------------------- /tests/convention/test002.sql: -------------------------------------------------------------------------------- 1 | -- test that casting to integer rounds and does not truncate 2 | 3 | SELECT case when CAST (4.8 AS INTEGER) = 5 AND CAST(4.2 AS INTEGER) = 4 then 'T' else 'F' end as result 4 | -------------------------------------------------------------------------------- /tests/convention/test003.sql: -------------------------------------------------------------------------------- 1 | -- check that that quantified expressions return NULL values as needed 2 | 3 | -- result header 4 | select case when (r1=5) and (r2=40) then 'T' else 'F' end as result 5 | from ( 6 | 7 | -- the query itself 8 | select sum(case when m then i else 0 end) as r1, sum(case when m is null then i else 0 end) r2 9 | from ( 10 | select i, x=some(select a from (values(1,1),(2,2),(3,3),(4,4),(NULL,5)) t(a,b) where b CAST('123 ' AS varchar(10)) then 'T' else 'F' end AS result 6 | -------------------------------------------------------------------------------- /tests/convention/test011.sql: -------------------------------------------------------------------------------- 1 | SELECT case when AVG(x)>0 then 'T' else 'F' end AS result 2 | FROM ( 3 | SELECT CAST(9223372036854775807 AS BIGINT) AS x 4 | UNION ALL 5 | SELECT CAST(9223372036854775807 AS BIGINT) 6 | ) AS t 7 | -------------------------------------------------------------------------------- /tests/convention/test012.sql: -------------------------------------------------------------------------------- 1 | -- check that aggregations are correctly extracted from a subquery 2 | SELECT case when (SELECT SUM(x))=42 then 'T' else 'F' end AS result 3 | FROM (VALUES (42)) AS t(x) 4 | -------------------------------------------------------------------------------- /tests/convention/test013.sql: -------------------------------------------------------------------------------- 1 | -- check that recursive queries work 2 | 3 | -- result header 4 | select case when (state='924875136138624795765391842546713928812469357397582614651238479489157263273946581') then 'T' else 'F' end as result 5 | from ( 6 | 7 | 8 | -- the query itself 9 | with recursive 10 | digits(value,ch) as (values(1,'1'),(2,'2'),(3,'3'),(4,'4'),(5,'5'),(6,'6'),(7,'7'),(8,'8'),(9,'9')), 11 | sudoku(state, next) as 12 | (select state, position(' ' in state) as next 13 | from (select '9 1 6 62 79 5 1 54 2 81 6935739 5826 46 7 915 32 3 46 ') s(state) 14 | union all 15 | select state, position(' ' in state) as next 16 | from (select substring(state from 1 for next-1) || try || substring(state from next+1) as state 17 | from sudoku, (select ch as try from digits) g 18 | where next > 0 and 19 | not exists(select 1 from (select value as pos from digits) s 20 | where try = substring(state from cast(floor((next-1)/9) as integer)*9+pos for 1) 21 | or try = substring(state from mod((next-1),9)+9*pos-8 for 1) 22 | or try = substring(state from mod(cast(floor((next-1)/3) as integer),3)*3+cast(floor((next-1)/27) as integer)*27+pos+cast(floor((pos-1)/3) as integer)*6 for 1)) 23 | ) c) 24 | select state from sudoku where next=0 25 | 26 | ) test 27 | -------------------------------------------------------------------------------- /tests/convention/test026.sql: -------------------------------------------------------------------------------- 1 | -- Test that an alias from the select clause can be used in the order by clause 2 | -- Should be standard compliant (CD 9075-2:201?(E) 7.16 ), 3 | -- but I cannot find the section that says so explicitly. 4 | select case when (true 5 | and (select a as b from (values (1)) t(a) order by b) = 1 6 | ) then 'T' else 'F' end from (values (1)) AS t 7 | --------------------------------------------------------------------------------