├── .github └── workflows │ └── ci.yml ├── .gitignore ├── .pylintrc ├── CITATION.cff ├── LICENSE ├── Pipfile ├── README.md ├── examples ├── commits_comments.rdbu ├── commits_with_comments.sql ├── communication_report.rdbu ├── communication_report.sql ├── datatypes.rdbu ├── empty.rdbu ├── join-where.rdbu ├── leader_commits_nl_comments.sql ├── nl_commits_leader_comments.sql └── simple.rdbu ├── pyproject.toml ├── src └── rdbunit │ ├── __init__.py │ └── __main__.py └── tests ├── test-mysql.sh ├── test-parts.sh ├── test-postgresql.sh └── test-sqlite.sh /.github/workflows/ci.yml: -------------------------------------------------------------------------------- 1 | name: rdbunit CI 2 | 3 | on: 4 | push: 5 | branches: 6 | - main 7 | pull_request: 8 | branches: 9 | - main 10 | 11 | jobs: 12 | test-python-versions: 13 | 14 | runs-on: ubuntu-latest 15 | strategy: 16 | matrix: 17 | python-version: ["3.7", "3.8", "3.9", "3.10", "3.11"] 18 | 19 | steps: 20 | - name: Checkout code 21 | uses: actions/checkout@main 22 | 23 | - name: Set up Python ${{ matrix.python-version }} 24 | uses: actions/setup-python@v4 25 | with: 26 | python-version: ${{ matrix.python-version }} 27 | 28 | - name: Test 29 | run: tests/test-parts.sh 30 | 31 | code-quality: 32 | runs-on: ubuntu-latest 33 | 34 | steps: 35 | - name: Checkout code 36 | uses: actions/checkout@main 37 | 38 | - name: Set up Python 3.9 39 | uses: actions/setup-python@v4 40 | with: 41 | python-version: 3.9 42 | 43 | - name: Install pipenv 44 | run: pip install pipenv 45 | 46 | - name: Install dependencies 47 | run: pipenv install --dev 48 | 49 | - name: Lint with pylint 50 | run: pipenv run pylint -r n src/rdbunit/__main__.py 51 | 52 | - name: Check style with pycodestyle 53 | run: pipenv run pycodestyle src/rdbunit/__main__.py 54 | 55 | test-databases: 56 | runs-on: ubuntu-latest 57 | 58 | services: 59 | mysql: 60 | image: mysql:5.7 61 | env: 62 | MYSQL_ROOT_PASSWORD: password 63 | ports: 64 | - 3306:3306 65 | options: --health-cmd="mysqladmin ping" --health-interval=10s --health-timeout=5s --health-retries=3 66 | 67 | postgres: 68 | image: postgres:13 69 | env: 70 | POSTGRES_USER: postgres 71 | POSTGRES_PASSWORD: postgres 72 | ports: 73 | - 5432:5432 74 | options: --health-cmd pg_isready --health-interval 10s --health-timeout 5s --health-retries 5 75 | 76 | steps: 77 | - name: Checkout repository 78 | uses: actions/checkout@main 79 | 80 | - name: Set up Python 81 | uses: actions/setup-python@v4 82 | with: 83 | python-version: 3.9 84 | 85 | - name: Install SQLite 86 | run: sudo apt-get install -y sqlite3 87 | 88 | - name: SQLite 89 | run: tests/test-sqlite.sh 90 | 91 | - name: PostgreSQL 92 | env: 93 | POSTGRES_USER: postgres 94 | PGPASSWORD: postgres 95 | run: tests/test-postgresql.sh 96 | 97 | - name: mySQL 98 | env: 99 | MYSQL_ROOT_PASSWORD: password 100 | run: tests/test-mysql.sh 101 | -------------------------------------------------------------------------------- /.gitignore: -------------------------------------------------------------------------------- 1 | .python-version 2 | Pipfile.lock 3 | dist 4 | -------------------------------------------------------------------------------- /.pylintrc: -------------------------------------------------------------------------------- 1 | [MESSAGES CONTROL] 2 | disable=R0205 3 | -------------------------------------------------------------------------------- /CITATION.cff: -------------------------------------------------------------------------------- 1 | cff-version: 1.2.0 2 | title: RDBUnit 3 | message: >- 4 | If you use this software, please cite, using the metadata from this file, 5 | both the article from preferred-citation and the software itself. 6 | preferred-citation: 7 | date-released: "2024-01-01" 8 | doi: "10.1109/MS.2023.3328788" 9 | title: "Unit Tests for SQL" 10 | authors: 11 | - family-names: "Spinellis" 12 | given-names: "Diomidis" 13 | type: "article" 14 | volume: "41" 15 | journal: "IEEE Software" 16 | publisher: "IEEE" 17 | start: "22" 18 | end: "26" 19 | type: software 20 | authors: 21 | - given-names: Diomidis 22 | family-names: Spinellis 23 | email: dds@aueb.gr 24 | affiliation: Athens University of Economics and Business 25 | orcid: 'https://orcid.org/0000-0003-4231-1897' 26 | repository-code: 'https://github.com/dspinellis/rdbunit/' 27 | keywords: 28 | - Unit testing 29 | - SQL 30 | - Relational query 31 | - SQLite 32 | - PostgreSQL 33 | - MariaDB 34 | - mySQL 35 | license: Apache-2.0 36 | -------------------------------------------------------------------------------- /LICENSE: -------------------------------------------------------------------------------- 1 | 2 | Apache License 3 | Version 2.0, January 2004 4 | http://www.apache.org/licenses/ 5 | 6 | TERMS AND CONDITIONS FOR USE, REPRODUCTION, AND DISTRIBUTION 7 | 8 | 1. Definitions. 9 | 10 | "License" shall mean the terms and conditions for use, reproduction, 11 | and distribution as defined by Sections 1 through 9 of this document. 12 | 13 | "Licensor" shall mean the copyright owner or entity authorized by 14 | the copyright owner that is granting the License. 15 | 16 | "Legal Entity" shall mean the union of the acting entity and all 17 | other entities that control, are controlled by, or are under common 18 | control with that entity. For the purposes of this definition, 19 | "control" means (i) the power, direct or indirect, to cause the 20 | direction or management of such entity, whether by contract or 21 | otherwise, or (ii) ownership of fifty percent (50%) or more of the 22 | outstanding shares, or (iii) beneficial ownership of such entity. 23 | 24 | "You" (or "Your") shall mean an individual or Legal Entity 25 | exercising permissions granted by this License. 26 | 27 | "Source" form shall mean the preferred form for making modifications, 28 | including but not limited to software source code, documentation 29 | source, and configuration files. 30 | 31 | "Object" form shall mean any form resulting from mechanical 32 | transformation or translation of a Source form, including but 33 | not limited to compiled object code, generated documentation, 34 | and conversions to other media types. 35 | 36 | "Work" shall mean the work of authorship, whether in Source or 37 | Object form, made available under the License, as indicated by a 38 | copyright notice that is included in or attached to the work 39 | (an example is provided in the Appendix below). 40 | 41 | "Derivative Works" shall mean any work, whether in Source or Object 42 | form, that is based on (or derived from) the Work and for which the 43 | editorial revisions, annotations, elaborations, or other modifications 44 | represent, as a whole, an original work of authorship. For the purposes 45 | of this License, Derivative Works shall not include works that remain 46 | separable from, or merely link (or bind by name) to the interfaces of, 47 | the Work and Derivative Works thereof. 48 | 49 | "Contribution" shall mean any work of authorship, including 50 | the original version of the Work and any modifications or additions 51 | to that Work or Derivative Works thereof, that is intentionally 52 | submitted to Licensor for inclusion in the Work by the copyright owner 53 | or by an individual or Legal Entity authorized to submit on behalf of 54 | the copyright owner. For the purposes of this definition, "submitted" 55 | means any form of electronic, verbal, or written communication sent 56 | to the Licensor or its representatives, including but not limited to 57 | communication on electronic mailing lists, source code control systems, 58 | and issue tracking systems that are managed by, or on behalf of, the 59 | Licensor for the purpose of discussing and improving the Work, but 60 | excluding communication that is conspicuously marked or otherwise 61 | designated in writing by the copyright owner as "Not a Contribution." 62 | 63 | "Contributor" shall mean Licensor and any individual or Legal Entity 64 | on behalf of whom a Contribution has been received by Licensor and 65 | subsequently incorporated within the Work. 66 | 67 | 2. Grant of Copyright License. Subject to the terms and conditions of 68 | this License, each Contributor hereby grants to You a perpetual, 69 | worldwide, non-exclusive, no-charge, royalty-free, irrevocable 70 | copyright license to reproduce, prepare Derivative Works of, 71 | publicly display, publicly perform, sublicense, and distribute the 72 | Work and such Derivative Works in Source or Object form. 73 | 74 | 3. Grant of Patent License. Subject to the terms and conditions of 75 | this License, each Contributor hereby grants to You a perpetual, 76 | worldwide, non-exclusive, no-charge, royalty-free, irrevocable 77 | (except as stated in this section) patent license to make, have made, 78 | use, offer to sell, sell, import, and otherwise transfer the Work, 79 | where such license applies only to those patent claims licensable 80 | by such Contributor that are necessarily infringed by their 81 | Contribution(s) alone or by combination of their Contribution(s) 82 | with the Work to which such Contribution(s) was submitted. If You 83 | institute patent litigation against any entity (including a 84 | cross-claim or counterclaim in a lawsuit) alleging that the Work 85 | or a Contribution incorporated within the Work constitutes direct 86 | or contributory patent infringement, then any patent licenses 87 | granted to You under this License for that Work shall terminate 88 | as of the date such litigation is filed. 89 | 90 | 4. Redistribution. You may reproduce and distribute copies of the 91 | Work or Derivative Works thereof in any medium, with or without 92 | modifications, and in Source or Object form, provided that You 93 | meet the following conditions: 94 | 95 | (a) You must give any other recipients of the Work or 96 | Derivative Works a copy of this License; and 97 | 98 | (b) You must cause any modified files to carry prominent notices 99 | stating that You changed the files; and 100 | 101 | (c) You must retain, in the Source form of any Derivative Works 102 | that You distribute, all copyright, patent, trademark, and 103 | attribution notices from the Source form of the Work, 104 | excluding those notices that do not pertain to any part of 105 | the Derivative Works; and 106 | 107 | (d) If the Work includes a "NOTICE" text file as part of its 108 | distribution, then any Derivative Works that You distribute must 109 | include a readable copy of the attribution notices contained 110 | within such NOTICE file, excluding those notices that do not 111 | pertain to any part of the Derivative Works, in at least one 112 | of the following places: within a NOTICE text file distributed 113 | as part of the Derivative Works; within the Source form or 114 | documentation, if provided along with the Derivative Works; or, 115 | within a display generated by the Derivative Works, if and 116 | wherever such third-party notices normally appear. The contents 117 | of the NOTICE file are for informational purposes only and 118 | do not modify the License. You may add Your own attribution 119 | notices within Derivative Works that You distribute, alongside 120 | or as an addendum to the NOTICE text from the Work, provided 121 | that such additional attribution notices cannot be construed 122 | as modifying the License. 123 | 124 | You may add Your own copyright statement to Your modifications and 125 | may provide additional or different license terms and conditions 126 | for use, reproduction, or distribution of Your modifications, or 127 | for any such Derivative Works as a whole, provided Your use, 128 | reproduction, and distribution of the Work otherwise complies with 129 | the conditions stated in this License. 130 | 131 | 5. Submission of Contributions. Unless You explicitly state otherwise, 132 | any Contribution intentionally submitted for inclusion in the Work 133 | by You to the Licensor shall be under the terms and conditions of 134 | this License, without any additional terms or conditions. 135 | Notwithstanding the above, nothing herein shall supersede or modify 136 | the terms of any separate license agreement you may have executed 137 | with Licensor regarding such Contributions. 138 | 139 | 6. Trademarks. This License does not grant permission to use the trade 140 | names, trademarks, service marks, or product names of the Licensor, 141 | except as required for reasonable and customary use in describing the 142 | origin of the Work and reproducing the content of the NOTICE file. 143 | 144 | 7. Disclaimer of Warranty. Unless required by applicable law or 145 | agreed to in writing, Licensor provides the Work (and each 146 | Contributor provides its Contributions) on an "AS IS" BASIS, 147 | WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or 148 | implied, including, without limitation, any warranties or conditions 149 | of TITLE, NON-INFRINGEMENT, MERCHANTABILITY, or FITNESS FOR A 150 | PARTICULAR PURPOSE. You are solely responsible for determining the 151 | appropriateness of using or redistributing the Work and assume any 152 | risks associated with Your exercise of permissions under this License. 153 | 154 | 8. Limitation of Liability. In no event and under no legal theory, 155 | whether in tort (including negligence), contract, or otherwise, 156 | unless required by applicable law (such as deliberate and grossly 157 | negligent acts) or agreed to in writing, shall any Contributor be 158 | liable to You for damages, including any direct, indirect, special, 159 | incidental, or consequential damages of any character arising as a 160 | result of this License or out of the use or inability to use the 161 | Work (including but not limited to damages for loss of goodwill, 162 | work stoppage, computer failure or malfunction, or any and all 163 | other commercial damages or losses), even if such Contributor 164 | has been advised of the possibility of such damages. 165 | 166 | 9. Accepting Warranty or Additional Liability. While redistributing 167 | the Work or Derivative Works thereof, You may choose to offer, 168 | and charge a fee for, acceptance of support, warranty, indemnity, 169 | or other liability obligations and/or rights consistent with this 170 | License. However, in accepting such obligations, You may act only 171 | on Your own behalf and on Your sole responsibility, not on behalf 172 | of any other Contributor, and only if You agree to indemnify, 173 | defend, and hold each Contributor harmless for any liability 174 | incurred by, or claims asserted against, such Contributor by reason 175 | of your accepting any such warranty or additional liability. 176 | 177 | END OF TERMS AND CONDITIONS 178 | 179 | APPENDIX: How to apply the Apache License to your work. 180 | 181 | To apply the Apache License to your work, attach the following 182 | boilerplate notice, with the fields enclosed by brackets "[]" 183 | replaced with your own identifying information. (Don't include 184 | the brackets!) The text should be enclosed in the appropriate 185 | comment syntax for the file format. We also recommend that a 186 | file or class name and description of purpose be included on the 187 | same "printed page" as the copyright notice for easier 188 | identification within third-party archives. 189 | 190 | Copyright [yyyy] [name of copyright owner] 191 | 192 | Licensed under the Apache License, Version 2.0 (the "License"); 193 | you may not use this file except in compliance with the License. 194 | You may obtain a copy of the License at 195 | 196 | http://www.apache.org/licenses/LICENSE-2.0 197 | 198 | Unless required by applicable law or agreed to in writing, software 199 | distributed under the License is distributed on an "AS IS" BASIS, 200 | WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 201 | See the License for the specific language governing permissions and 202 | limitations under the License. 203 | -------------------------------------------------------------------------------- /Pipfile: -------------------------------------------------------------------------------- 1 | [[source]] 2 | url = "https://pypi.org/simple" 3 | verify_ssl = true 4 | name = "pypi" 5 | 6 | [packages] 7 | 8 | [dev-packages] 9 | pycodestyle = "*" 10 | pylint = "*" 11 | build = "*" 12 | twine = "*" 13 | 14 | [requires] 15 | python_version = "3" 16 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # RDBUnit: Unit testing for SQL queries 2 | 3 | [![rdbunit CI](https://github.com/dspinellis/rdbunit/actions/workflows/ci.yml/badge.svg)](https://github.com/dspinellis/rdbunit/actions/workflows/ci.yml) 4 | 5 | 6 | **RDBUnit** is a unit testing framework for relational database SQL queries. 7 | It allows you to express in a simple way the setup prior to a query, 8 | the query, and the expected results. 9 | RDBUnit can test `SELECT` queries as well as queries that are used 10 | for creating tables and views. 11 | All types of queries can be either embedded into the test script, or 12 | they can be included from an external file. 13 | The tables for the input and the expected results can be created with 14 | minimal ceremony: RDBUnit will automatically infer the types of the 15 | tables' fields. 16 | 17 | For complex relational OLAP queries *RDBUnit* can be combined particularly 18 | effectively with the [simple-rolap](https://github.com/dspinellis/simple-rolap) 19 | relational online analytical processing framework. 20 | You can find a complete tutorial on using *RDBUnit* with *simple-rolap* 21 | for mining Git repositories in a 22 | [technical briefing](https://doi.org/10.5281/zenodo.7513793) 23 | presented at the 2017 International Conference on Software Engineering. 24 | 25 | You can cite this work as follows. 26 | 27 | * Diomidis Spinellis. Unit Tests for SQL. _IEEE Software_, vol. 41, no. 1, pp. 31–34, Jan.-Feb. 2024. doi: [10.1109/MS.2023.3328788](https://doi.org/10.1109/MS.2023.3328788). 28 | 29 | ## Installation 30 | 31 | ### Using Pip 32 | ```sh 33 | pip install rdbunit 34 | ``` 35 | 36 | ### From source 37 | * Clone this repository 38 | ``` 39 | git clone --depth=1 https://github.com/dspinellis/rdbunit.git 40 | cd rdbunit 41 | pipenv shell 42 | pip install . 43 | ``` 44 | 45 | ## Test specification 46 | For every SQL query you want to test, create an *RDBUnit* file that 47 | specifies the query's input, execution, and expected result. 48 | The setup-query-results sequence can be specified multiple times within 49 | a test file. 50 | 51 | ### Simple example 52 | The following example illustrates this concept. 53 | 54 | #### Step 1: Create the unit test specification 55 | Create a file named `max_revenue.rdbu` with the following contents. 56 | 57 | ``` 58 | BEGIN SETUP 59 | sales: 60 | month revenue 61 | March 130 62 | April 50 63 | END 64 | 65 | BEGIN SELECT 66 | SELECT MAX(revenue) as max_revenue FROM sales; 67 | END 68 | 69 | BEGIN RESULT 70 | max_revenue 71 | 130 72 | END 73 | ``` 74 | 75 | #### Step 2: Run the unit test 76 | Run the unit test to see its result as follows. 77 | 78 | ``` 79 | $ rdbunit --database=sqlite max_revenue.rdbu | sqlite3 80 | ok 1 - max_revenue.rdbu: test_select_result 81 | 1..1 82 | ``` 83 | 84 | ### Table data details 85 | The input and output are specified as table contents. 86 | The input starts with a line containing the words `BEGIN SETUP`, 87 | while the results start with a line containing the words 88 | `BEGIN RESULTS`. 89 | The input and output are specified by first giving a table's name, 90 | followed by a colon. 91 | The name may be prefixed by the name of a database where the table 92 | is to reside, followed by a dot. 93 | The next row contains the names of table's fields, separated by spaces. 94 | Then come the table's data, which are terminated by a blank line, 95 | or by the word `END`. 96 | The table data automatically derive the fields' data types from those of 97 | the first row. 98 | (For this reason avoid specifying NULL values in the first row.) 99 | 100 | More than one table can be specified in the setup. 101 | In the results the table name is not specified, if the tested 102 | query is a selection statement, rather than a table or view creation. 103 | 104 | 105 | ### Setup example 106 | ``` 107 | BEGIN SETUP 108 | contacts: 109 | name registered value reg_date 110 | John true 12 '2015-03-02' 111 | Mary false 10 '2012-03-02' 112 | END 113 | ``` 114 | 115 | ### Results example (named table) 116 | Named table results are used with `CREATE` queries. 117 | ``` 118 | BEGIN RESULT 119 | leadership.nl_commits_leader_comments: 120 | project_id n 121 | 1 3 122 | END 123 | ``` 124 | 125 | ### Results example (unnamed set) 126 | Unnamed set results are used with `SELECT` queries. 127 | ``` 128 | BEGIN RESULT 129 | name registered value reg_date a 130 | John True 12 '2015-03-02' Null 131 | END 132 | ``` 133 | 134 | ### Tested query 135 | The query to test is either specified inline 136 | with a `BEGIN SELECT` (for selection queries) 137 | or with `BEGIN CREATE` (for creation and insert or update queries) 138 | statement, 139 | or by specifying a file through the corresponding `INCLUDE SELECT` or 140 | `INCLUDE CREATE` statement. 141 | An `INCLUDE SELECT` or `INCLUDE CREATE` statement can be combined 142 | with a corresponding `BEGIN SELECT` or `BEGIN CREATE` statement 143 | to customize the query or database for the testing environment. 144 | For example, 145 | this may be needed to add a unique table index to simulate a 146 | corresponding primary key or to delete an input table row to 147 | obtain an empty table. 148 | 149 | ### Inline example 150 | ``` 151 | BEGIN SELECT 152 | SELECT *, NULL AS a FROM contacts WHERE registered; 153 | END 154 | ``` 155 | 156 | ### External query example 157 | ``` 158 | INCLUDE CREATE nl_commits_leader_comments.sql 159 | ``` 160 | 161 | ## Unit testing 162 | To run the tests run *RDBUnit* piping its output to one of the supported 163 | relational database systems (current *MySQL*, *PostgreSQL*, and *sqLite*). 164 | A number of command-line flags allow you to tailor the operation of 165 | *RDBUnit*. 166 | When running, *RDBUnit* will report on its output something like 167 | `ok 1 - recent_commit_projects.rdbu: test_stratsel.recent_commit_projects` 168 | for each succeeding test case and 169 | `not ok 1 - project_stars.rdbu: test_stratsel.project_stars` for each failing 170 | test case. 171 | A final line will list the number of succeeding and failing test cases. 172 | By default *RDBUnit* creates and operates on temporary databases, 173 | whose name is prefixed with the word `test_`. 174 | 175 | By specifying the `--results` option (or the equivalent `-r` short option) 176 | you can direct _rdbunit_ to display the table generated for each test. 177 | This is useful for debugging test failures or for generating reference data 178 | (after suitable manual verification). 179 | 180 | ### Execution example (SQLite) 181 | ```sh 182 | $ rdbunit --database=sqlite recent_commit_projects.rdbu | sqlite3 183 | ok 1 - recent_commit_projects.rdbu: test_stratsel.recent_commit_projects 184 | ``` 185 | 186 | ### Execution example (MySQL) 187 | ```sh 188 | $ rdbunit commits_comments.rdbu | mysql -u root -p -N 189 | Enter password: 190 | ok 1 - commits_comments.rdbu: test_leadership.nl_commits_leader_comments 191 | ok 2 - commits_comments.rdbu: test_leadership.leader_commits_nl_comments 192 | ok 3 - commits_comments.rdbu: test_leadership.commits_with_comments 193 | 1..3 194 | ``` 195 | 196 | ### Execution example (PostgreSQL) 197 | ```sh 198 | $ rdbunit --database=postgresql commits_comments.rdbu | psql -U ght -h 127.0.0.1 -t -q ghtorrent 199 | ok 1 - commits_comments.rdbu: test_leadership.nl_commits_leader_comments 200 | 201 | ok 2 - commits_comments.rdbu: test_leadership.leader_commits_nl_comments 202 | 203 | ok 3 - commits_comments.rdbu: test_leadership.commits_with_comments 204 | 205 | 1..3 206 | ``` 207 | 208 | ## Troubleshooting 209 | When unit tests fail you can troubleshoot them as follows. 210 | 211 | ### Test fails due to a syntax error 212 | Example: 213 | ``` 214 | $ rdbunit --database=sqlite mytest.rdbu | sqlite3 215 | Error: near line 26: near ".": syntax error 216 | not ok 1 - mytest.rdbu: mytest 217 | 1..1 218 | ``` 219 | Pipe the output of _rdbunit_ to `cat -n` to see the offending line. 220 | ``` 221 | $ rdbunit --database=sqlite mytest.rdbu | cat -n 222 | ``` 223 | 224 | ## Test fails due to incorrect results 225 | Example: 226 | ``` 227 | $ rdbunit --database=sqlite fileid_to_global_map.rdbu | sqlite3 228 | not ok 1 - fileid_to_global_map.rdbu: fileid_to_global_map 229 | 1..1 230 | ``` 231 | Re-run the specific test 232 | with the `--results` option to see the generated output or 233 | with the `--compare` option to see the difference in the obtained result sets. 234 | ``` 235 | $ rdbunit --database=sqlite --results fileid_to_global_map.rdbu | sqlite3 236 | not ok 1 - fileid_to_global_map.rdbu: fileid_to_global_map 237 | Result set: 238 | 2|3|1 239 | 2|5|2 240 | 5|1|3 241 | 5|2|1 242 | 5|3|4 243 | 1..1 244 | 245 | $ rdbunit --database=sqlite fileid_to_global_map.rdbu --compare | sqlite3 246 | not ok 1 - fileid_to_global_map.rdbu: fileid_to_global_map 247 | Non expected records in result set: 248 | 5|3|4 249 | Missing records in result set: 250 | 4|3|4 251 | 1..1 252 | 253 | ``` 254 | 255 | ## Development 256 | 257 | Contributions via GitHub pull requests are welcomed. 258 | Each contribution passes through continuous integration, 259 | which verifies the code's style (_pycodestyle_) and checks for errors 260 | (_pylint_). 261 | It also tests the input and output of _RDBunit_ and its operation on the 262 | three supported relational database systems. 263 | On a local host, after creating a virtual environment (`pipenv`), 264 | entering it (`pipenv shell`), and 265 | installing the required development dependencies (`pipenv install --dev`), 266 | you can run the following commands. 267 | 268 | * `pycodestyle src/rdbunit/__main__.py` 269 | * `pylint src/rdbunit/__main__.py` 270 | * `tests/test-parts.sh` 271 | * `tests/test-sqlite.sh` 272 | -------------------------------------------------------------------------------- /examples/commits_comments.rdbu: -------------------------------------------------------------------------------- 1 | # Commits by leaders commented by non-leaders and the opposite 2 | 3 | # Number of results 4 | # committer commenter 5 | # -------------------- 6 | # non-leader non-leader 2 7 | # non-leader leader 3 8 | # leader non-leader 4 9 | # leader leader 5 10 | # Total 14 11 | 12 | BEGIN SETUP 13 | leadership.project_leaders: 14 | project_id user_id 15 | 1 20 16 | 2 21 17 | 18 | 19 | leadership.yearly_commits: 20 | id project_id author_id 21 | 1 1 51 22 | 2 1 52 23 | 24 | # 3: non-leader leader 25 | 3 1 53 26 | 4 1 53 27 | 5 1 54 28 | # Uncommented 29 | 105 1 54 30 | 31 | # 4: leader non-leader 32 | 6 1 20 33 | 7 1 20 34 | 8 1 20 35 | 9 1 20 36 | # Uncommented 37 | 109 1 20 38 | 39 | 10 1 20 40 | 11 1 20 41 | 12 1 20 42 | 13 1 20 43 | 14 1 20 44 | 15 1 21 45 | 46 | leadership.yearly_commit_comments: 47 | commit_id user_id 48 | 1 51 49 | 1 52 50 | 2 51 51 | 52 | 3 20 53 | 4 20 54 | 4 20 55 | 5 20 56 | 57 | 6 51 58 | 7 51 59 | 8 51 60 | 9 51 61 | 9 51 62 | 9 52 63 | 64 | 10 20 65 | 11 20 66 | 12 20 67 | 13 20 68 | 14 20 69 | 70 | 15 21 71 | END 72 | 73 | INCLUDE CREATE nl_commits_leader_comments.sql 74 | 75 | BEGIN RESULT 76 | leadership.nl_commits_leader_comments: 77 | project_id n 78 | 1 3 79 | END 80 | 81 | INCLUDE CREATE leader_commits_nl_comments.sql 82 | 83 | BEGIN RESULT 84 | leadership.leader_commits_nl_comments: 85 | project_id n 86 | 1 4 87 | END 88 | 89 | INCLUDE CREATE commits_with_comments.sql 90 | 91 | BEGIN RESULT 92 | leadership.commits_with_comments: 93 | project_id n 94 | 1 15 95 | END 96 | -------------------------------------------------------------------------------- /examples/commits_with_comments.sql: -------------------------------------------------------------------------------- 1 | -- Number of commits that have comments per project 2 | 3 | create table leadership.commits_with_comments AS 4 | select project_commits.project_id as project_id, 5 | count(*) as n 6 | 7 | from ( 8 | select distinct project_leaders.project_id, yearly_commits.id 9 | from leadership.project_leaders 10 | 11 | left join leadership.yearly_commits 12 | on yearly_commits.project_id = project_leaders.project_id 13 | 14 | inner join leadership.yearly_commit_comments 15 | on yearly_commits.id = yearly_commit_comments.commit_id 16 | 17 | ) as project_commits 18 | 19 | group by project_commits.project_id; 20 | -------------------------------------------------------------------------------- /examples/communication_report.rdbu: -------------------------------------------------------------------------------- 1 | BEGIN SETUP 2 | leadership.project_leaders: 3 | project_id 4 | 1 5 | 2 6 | 3 7 | 8 | leadership.nl_commits_leader_comments: 9 | project_id n 10 | 1 12 11 | 12 | leadership.leader_commits_nl_comments: 13 | project_id n 14 | 1 0 15 | 16 | leadership.nl_issues_leader_comments: 17 | project_id n 18 | 2 5 19 | 20 | leadership.leader_issues_nl_comments: 21 | project_id n 22 | 2 0 23 | 24 | leadership.commits_with_comments: 25 | project_id n 26 | 1 0 27 | 28 | leadership.issues_with_comments: 29 | project_id n 30 | 1 8 31 | 2 9 32 | END 33 | 34 | INCLUDE SELECT communication_report.sql 35 | 36 | BEGIN RESULT 37 | project_id nl_commits_leader_comments leader_commits_nl_comments nl_issues_leader_comments leader_issues_nl_comments commits_with_comments issues_with_comments 38 | 1 12 0 0 0 0 8 39 | 2 0 0 5 0 0 9 40 | 3 0 0 0 0 0 0 41 | END 42 | -------------------------------------------------------------------------------- /examples/communication_report.sql: -------------------------------------------------------------------------------- 1 | -- Number of commits that have comments per project 2 | 3 | select project_leaders.project_id as project_id, 4 | coalesce(nl_commits_leader_comments.n, 0) as nl_commits_leader_comments, 5 | coalesce(leader_commits_nl_comments.n, 0) as leader_commits_nl_comments, 6 | coalesce(nl_issues_leader_comments.n, 0) as nl_issues_leader_comments, 7 | coalesce(leader_issues_nl_comments.n, 0) as leader_issues_nl_comments, 8 | coalesce(commits_with_comments.n, 0) as commits_with_comments, 9 | coalesce(issues_with_comments.n, 0) as issues_with_comments 10 | 11 | from leadership.project_leaders 12 | 13 | left join leadership.nl_commits_leader_comments 14 | on project_leaders.project_id = nl_commits_leader_comments.project_id 15 | 16 | left join leadership.leader_commits_nl_comments 17 | on project_leaders.project_id = leader_commits_nl_comments.project_id 18 | 19 | left join leadership.nl_issues_leader_comments 20 | on project_leaders.project_id = nl_issues_leader_comments.project_id 21 | 22 | left join leadership.leader_issues_nl_comments 23 | on project_leaders.project_id = leader_issues_nl_comments.project_id 24 | 25 | left join leadership.commits_with_comments 26 | on project_leaders.project_id = commits_with_comments.project_id 27 | 28 | left join leadership.issues_with_comments 29 | on project_leaders.project_id = issues_with_comments.project_id; 30 | -------------------------------------------------------------------------------- /examples/datatypes.rdbu: -------------------------------------------------------------------------------- 1 | # Demonstrate how rdbunit handles diverse data types 2 | BEGIN SETUP 3 | contacts: 4 | name registered value reg_date 5 | John true 12 '2015-03-02' 6 | Mary false 10 '2012-03-02' 7 | END 8 | 9 | BEGIN SELECT 10 | SELECT *, NULL AS a FROM contacts WHERE registered; 11 | END 12 | 13 | BEGIN RESULT 14 | name registered value reg_date a 15 | John True 12 '2015-03-02' Null 16 | END 17 | -------------------------------------------------------------------------------- /examples/empty.rdbu: -------------------------------------------------------------------------------- 1 | BEGIN SETUP 2 | sales: 3 | month revenue 4 | March 130 5 | April 50 6 | END 7 | 8 | BEGIN SELECT 9 | SELECT month FROM sales WHERE revenue > 1000; 10 | END 11 | 12 | BEGIN RESULT 13 | month 14 | END 15 | -------------------------------------------------------------------------------- /examples/join-where.rdbu: -------------------------------------------------------------------------------- 1 | BEGIN SETUP 2 | Sales: 3 | Area_id Month Revenue Final 4 | 1 3 130 TRUE 5 | 1 4 110 TRUE 6 | 2 3 30 TRUE 7 | 2 4 20 TRUE 8 | 3 3 90 FALSE 9 | 3 4 80 FALSE 10 | 11 | Areas: 12 | Id Name 13 | 1 North 14 | 2 South 15 | 16 | Months: 17 | Id Name 18 | 3 March 19 | 4 April 20 | END 21 | 22 | BEGIN SELECT 23 | SELECT Areas.Name AS Area_name, Months.Name as Month_name,Revenue 24 | FROM Sales 25 | LEFT JOIN Areas ON Sales.Area_id = Areas.Id 26 | LEFT JOIN Months ON Sales.Month = Months.Id 27 | WHERE Final; 28 | END 29 | 30 | BEGIN RESULT 31 | Area_name Month_name Revenue 32 | North March 130 33 | South March 30 34 | North April 110 35 | South April 20 36 | END 37 | -------------------------------------------------------------------------------- /examples/leader_commits_nl_comments.sql: -------------------------------------------------------------------------------- 1 | -- Commits by leaders commented by non-leaders 2 | 3 | create table leadership.leader_commits_nl_comments AS 4 | select project_commits.project_id as project_id, 5 | count(*) as n 6 | 7 | from ( 8 | select distinct project_leaders.project_id, yearly_commits.id 9 | from leadership.project_leaders 10 | 11 | left join leadership.yearly_commits 12 | on yearly_commits.project_id = project_leaders.project_id 13 | 14 | left join leadership.yearly_commit_comments 15 | on yearly_commits.id = yearly_commit_comments.commit_id 16 | 17 | where yearly_commits.author_id = project_leaders.user_id and 18 | yearly_commit_comments.user_id != project_leaders.user_id 19 | ) as project_commits 20 | 21 | group by project_commits.project_id; 22 | -------------------------------------------------------------------------------- /examples/nl_commits_leader_comments.sql: -------------------------------------------------------------------------------- 1 | -- Commits by non-leaders commented by the leader 2 | 3 | create table leadership.nl_commits_leader_comments AS 4 | select project_commits.project_id as project_id, 5 | count(*) as n 6 | 7 | from ( 8 | select distinct project_leaders.project_id, yearly_commits.id 9 | from leadership.project_leaders 10 | 11 | left join leadership.yearly_commits 12 | on yearly_commits.project_id = project_leaders.project_id 13 | 14 | left join leadership.yearly_commit_comments 15 | on yearly_commits.id = yearly_commit_comments.commit_id 16 | 17 | where yearly_commit_comments.user_id = project_leaders.user_id and 18 | yearly_commits.author_id != project_leaders.user_id 19 | ) as project_commits 20 | 21 | group by project_commits.project_id; 22 | -------------------------------------------------------------------------------- /examples/simple.rdbu: -------------------------------------------------------------------------------- 1 | BEGIN SETUP 2 | sales: 3 | month revenue 4 | March 130 5 | April 50 6 | END 7 | 8 | BEGIN SELECT 9 | SELECT MAX(revenue) as max_revenue FROM sales; 10 | END 11 | 12 | BEGIN RESULT 13 | max_revenue 14 | 130 15 | END 16 | -------------------------------------------------------------------------------- /pyproject.toml: -------------------------------------------------------------------------------- 1 | [build-system] 2 | requires = ["hatchling"] 3 | build-backend = "hatchling.build" 4 | 5 | [project] 6 | name = "rdbunit" 7 | version = "1.1.2" 8 | authors = [ 9 | { name="Diomidis Spinellis", email="dds@aueb.gr" }, 10 | ] 11 | description = "RDBUnit is a unit testing framework for relational database queries." 12 | readme = "README.md" 13 | requires-python = ">=3.7" 14 | license = {file = "LICENSE"} 15 | keywords = ["unit testing", "SQL", "mySQL", "PostgreSQL", "SQLite"] 16 | homepage = "https://github.com/dspinellis/rdbunit" 17 | 18 | classifiers = [ 19 | "Development Status :: 5 - Production/Stable", 20 | "Environment :: Console", 21 | "Intended Audience :: Developers", 22 | "License :: OSI Approved :: Apache Software License", 23 | "Operating System :: POSIX", 24 | "Operating System :: MacOS", 25 | "Operating System :: Unix", 26 | "Operating System :: Microsoft :: Windows", 27 | "Programming Language :: Python", 28 | "Programming Language :: Python :: 3", 29 | "Topic :: Software Development :: Testing :: Unit" 30 | ] 31 | 32 | [project.urls] 33 | Homepage = "https://github.com/dspinellis/rdbunit" 34 | Documentation = "https://github.com/dspinellis/rdbunit" 35 | Repository = "https://github.com/dspinellis/rdbunit.git" 36 | "Bug Tracker" = "https://github.com/dspinellis/rdbunit/issues" 37 | 38 | [project.scripts] 39 | rdbunit = "rdbunit.__main__:main" 40 | -------------------------------------------------------------------------------- /src/rdbunit/__init__.py: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/dspinellis/rdbunit/56b175b45f836989d752c8b3c41907dd9e54c248/src/rdbunit/__init__.py -------------------------------------------------------------------------------- /src/rdbunit/__main__.py: -------------------------------------------------------------------------------- 1 | #!/usr/bin/env python3 2 | # 3 | # Copyright 2017-2023 Diomidis Spinellis 4 | # 5 | # Licensed under the Apache License, Version 2.0 (the "License"); 6 | # you may not use this file except in compliance with the License. 7 | # You may obtain a copy of the License at 8 | # 9 | # http://www.apache.org/licenses/LICENSE-2.0 10 | # 11 | # Unless required by applicable law or agreed to in writing, software 12 | # distributed under the License is distributed on an "AS IS" BASIS, 13 | # WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 14 | # See the License for the specific language governing permissions and 15 | # limitations under the License. 16 | # 17 | 18 | # Disable useless object inheritance for compatibility with Python 2 19 | 20 | """ 21 | SQL Unit Test runner 22 | 23 | Run examples: 24 | python rdbunit.py [-e] leader_commits_nl_comments.rdbu | 25 | mysql -u root -p$DBPASS -N 26 | 27 | python rdbunit.py --database=postgresql communication_report.rdbu | 28 | psql -U ght -h 127.0.0.1 -t -q ghtorrent 29 | 30 | """ 31 | 32 | from __future__ import absolute_import 33 | from __future__ import print_function 34 | import argparse 35 | import os 36 | import re 37 | import shlex 38 | import sys 39 | 40 | # Values and their corresponding SQL data types 41 | RE_INTEGER = re.compile(r'\d+$') 42 | RE_REAL = re.compile(r'((\d+\.\d*)|(\d*\.\d+)([Ee]-?\d+)?)|\d+[Ee]-?\d+$') 43 | RE_DATE = re.compile(r'\d{4}-\d\d-\d\d$') 44 | RE_TIME = re.compile(r'\d+:\d+:\d+$') 45 | RE_TIMESTAMP = re.compile(r'\d{4}-\d\d-\d\d$ \d+:\d+:\d+$') 46 | RE_BOOLEAN = re.compile(r'(true|false)$', re.IGNORECASE) 47 | 48 | RE_INCLUDE_CREATE = re.compile(r'INCLUDE\s+CREATE\s+(.*)$') 49 | RE_INCLUDE_SELECT = re.compile(r'INCLUDE\s+SELECT\s+(.*)$') 50 | 51 | RE_FULL_CREATE_INDEX = re.compile(r'CREATE\s+INDEX\s+[^;]+;', re.IGNORECASE) 52 | RE_PARTIAL_CREATE_INDEX = re.compile(r'CREATE\s+INDEX\b[^;]*$', re.IGNORECASE) 53 | RE_CLEAR_TO_SEMICOLON = re.compile(r'^[^;]*;') 54 | 55 | RE_FULL_ATTACH_DATABASE = re.compile(r'ATTACH\s+[^;]+;', re.IGNORECASE) 56 | 57 | # Reference to a table in a database \1 is the database \2 is the table name 58 | RE_DB_TABLESPEC = re.compile(r'([A-Za-z_]\w*)\.([A-Za-z_]\w*)') 59 | # Remove the test_ prefix from a string 60 | RE_NON_TEST = re.compile(r'^test_') 61 | 62 | 63 | class Database(object): 64 | """Generic database commands""" 65 | @staticmethod 66 | def initialize(): 67 | """Issue engine-specific initialization commands""" 68 | return 69 | 70 | @staticmethod 71 | def drop(name): 72 | """Remove the specified database""" 73 | # pylint: disable=unused-argument 74 | return 75 | 76 | @staticmethod 77 | def use(name): 78 | """Use by default the specified database""" 79 | # pylint: disable=unused-argument 80 | return 81 | 82 | @staticmethod 83 | def boolean_value(val): 84 | """Return the SQL representation of a Boolean value.""" 85 | if val.lower() == 'false': 86 | return 'FALSE' 87 | if val.lower() == 'null': 88 | return 'NULL' 89 | return 'TRUE' 90 | 91 | 92 | class DatabaseMySQL(Database): 93 | """SQL-specific commands for MySQL""" 94 | @staticmethod 95 | def drop(name): 96 | """Remove the specified database""" 97 | print('DROP DATABASE IF EXISTS ' + name + ';') 98 | 99 | @staticmethod 100 | def create_db(name): 101 | """Create the specified database""" 102 | print('CREATE DATABASE ' + name + ';') 103 | 104 | @staticmethod 105 | def create_view(name): 106 | """Create the specified view""" 107 | print('CREATE VIEW ' + name + ' AS') 108 | 109 | @staticmethod 110 | def use(name): 111 | """Use by default the specified database""" 112 | print('USE ' + name + ';') 113 | 114 | 115 | class DatabasePostgreSQL(Database): 116 | """SQL-specific commands for PostgreSQL""" 117 | @staticmethod 118 | def initialize(): 119 | """Issue engine-specific initialization commands""" 120 | # Don't show warnings when IF EXISTS doesn't exist 121 | print("\\set ON_ERROR_STOP true\nSET client_min_messages='ERROR';") 122 | 123 | @staticmethod 124 | def drop(name): 125 | """Remove the specified database""" 126 | print('DROP SCHEMA IF EXISTS ' + name + ' CASCADE;') 127 | 128 | @staticmethod 129 | def create_db(name): 130 | """Create the specified database""" 131 | print('CREATE SCHEMA ' + name + ';') 132 | 133 | @staticmethod 134 | def create_view(name): 135 | """Create the specified view""" 136 | print('CREATE VIEW ' + name + ' AS') 137 | 138 | @staticmethod 139 | def use(name): 140 | """Use by default the specified database""" 141 | print('SET search_path TO ' + name + ';') 142 | 143 | 144 | class DatabaseSQLite(Database): 145 | """SQL-specific commands for SQLite""" 146 | @staticmethod 147 | def create_db(name): 148 | """Create the specified database""" 149 | print('ATTACH DATABASE ":memory:" AS ' + name + ';') 150 | 151 | @staticmethod 152 | def create_view(name): 153 | """Create the specified view""" 154 | print('CREATE TEMP VIEW ' + name + ' AS') 155 | 156 | @staticmethod 157 | def boolean_value(val): 158 | """Return the SQL representation of a Boolean value. 159 | SQLite requires integers.""" 160 | if val.lower() == 'false': 161 | return '0' 162 | if val.lower() == 'null': 163 | return 'NULL' 164 | return '1' 165 | 166 | 167 | def create_database(dbengine, created_databases, name): 168 | """Create a database with the specified name""" 169 | if name is None or name in created_databases: 170 | return 171 | dbengine.drop(name) 172 | dbengine.create_db(name) 173 | if name != 'default': 174 | created_databases.append(name) 175 | 176 | 177 | class SqlType(object): 178 | """An SQL type's name and its value representation""" 179 | def __init__(self, dbengine, value): 180 | # pylint: disable=too-many-branches 181 | def boolean_value(val): 182 | """Return the engine-specific Boolean representation of val.""" 183 | return self.dbengine.boolean_value(val) 184 | 185 | def quoted_value(val): 186 | """Return the SQL representation of a quoted value.""" 187 | if val.lower() == 'null': 188 | return 'NULL' 189 | return "'" + val + "'" 190 | 191 | def unquoted_value(val): 192 | """Return the SQL representation of an unquoted value.""" 193 | if val.lower() == 'null': 194 | return 'NULL' 195 | return str(val) 196 | 197 | self.dbengine = dbengine 198 | if RE_INTEGER.match(value): 199 | self.name = 'INTEGER' 200 | self.sql_repr = unquoted_value 201 | elif RE_REAL.match(value): 202 | self.name = 'REAL' 203 | self.sql_repr = unquoted_value 204 | elif RE_DATE.match(value): 205 | self.name = 'DATE' 206 | self.sql_repr = quoted_value 207 | elif RE_TIME.match(value): 208 | self.name = 'TIME' 209 | self.sql_repr = quoted_value 210 | elif RE_TIMESTAMP.match(value): 211 | self.name = 'TIMESTAMP' 212 | self.sql_repr = quoted_value 213 | elif RE_BOOLEAN.match(value): 214 | self.name = 'BOOLEAN' 215 | self.sql_repr = boolean_value 216 | else: 217 | self.name = 'VARCHAR(255)' 218 | self.sql_repr = quoted_value 219 | 220 | def get_name(self): 221 | """Return a type's name""" 222 | return self.name 223 | 224 | def get_value(self, val): 225 | """Return a type's value, suitably quoted""" 226 | return self.sql_repr(val) 227 | 228 | 229 | def create_table(dbengine, table_name, column_names, values): 230 | """Create the specified table taking as a hint for types the values. 231 | Return the type objects associated with the values.""" 232 | print('DROP TABLE IF EXISTS ' + table_name + ';') 233 | # Create data type objects from the values 234 | types = [SqlType(dbengine, x) for x in shlex.split(values)] 235 | print('CREATE TABLE ' + table_name + '(' + 236 | ', '.join([n + ' ' + t.get_name() for n, t in zip( 237 | column_names, types)]) + ');') 238 | return types 239 | 240 | 241 | def create_test_cases(args, test_name, file_input): 242 | """Create the test cases with the specified name in input""" 243 | print('-- Input from ' + test_name) 244 | if args.database == 'mysql': 245 | dbengine = DatabaseMySQL() 246 | elif args.database == 'postgresql': 247 | dbengine = DatabasePostgreSQL() 248 | elif args.database == 'sqlite': 249 | dbengine = DatabaseSQLite() 250 | else: 251 | sys.exit('Unsupported database: ' + args.database) 252 | dbengine.initialize() 253 | if not args.existing_database: 254 | database_name = os.getenv('ROLAPDB') 255 | if not database_name: 256 | database_name = 'test_default' 257 | create_database(dbengine, [], database_name) 258 | dbengine.use(database_name) 259 | process_test(args, dbengine, test_name, file_input) 260 | 261 | 262 | def process_sql(file_name, db_re): 263 | """Process an SQL statement, substituting referenced databases specified 264 | in the db_re compiled regular expression with the corresponding test one""" 265 | with open(file_name, encoding="UTF-8") as query: 266 | for line in query: 267 | line = line.rstrip() 268 | 269 | # Remove index creation and database attachment in single line 270 | line = re.sub(RE_FULL_CREATE_INDEX, '', line) 271 | line = re.sub(RE_FULL_ATTACH_DATABASE, '', line) 272 | 273 | # Remove CREATE INDEX statements spanning multiple lines 274 | if RE_PARTIAL_CREATE_INDEX.search(line) is not None: 275 | first_part = re.sub(RE_PARTIAL_CREATE_INDEX, '', line) 276 | last_line = '' 277 | for query_line in query: 278 | # Skip lines as INDEX statment continues 279 | if query_line.find(';') == -1: 280 | continue 281 | last_line = query_line 282 | break 283 | line = first_part + re.sub(RE_CLEAR_TO_SEMICOLON, '', 284 | last_line) 285 | 286 | line = db_re.sub(r'test_\1.', line) 287 | print(line) 288 | 289 | 290 | def make_db_re(dbs): 291 | """Return a compiled regular expression for identifying the 292 | databases passed in the array""" 293 | if dbs: 294 | non_test_dbs = [RE_NON_TEST.sub('', x) for x in dbs] 295 | database_re = r'\b(' + '|'.join(non_test_dbs) + r')\.' 296 | print('-- Database RE: ' + database_re) 297 | else: 298 | # This RE cannot match any string 299 | database_re = r'(A\bB)' 300 | return re.compile(database_re, re.IGNORECASE) 301 | 302 | 303 | def verify_content(args, number, test_name, case_name): 304 | """Verify that the specified table has the same content as the 305 | table test_expected""" 306 | print(f""" 307 | SELECT CASE WHEN 308 | (SELECT COUNT(*) FROM ( 309 | SELECT * FROM test_expected 310 | UNION 311 | SELECT * FROM {case_name} 312 | ) AS u1) = (SELECT COUNT(*) FROM test_expected) AND 313 | (SELECT COUNT(*) FROM ( 314 | SELECT * FROM test_expected 315 | UNION 316 | SELECT * FROM {case_name} 317 | ) AS u2) = (SELECT COUNT(*) FROM {case_name})""") 318 | print(f"""THEN 'ok {number} - {test_name}: {case_name}' ELSE 319 | 'not ok {number} - {test_name}: {case_name}' END;\n""" 320 | ) 321 | if args.results: 322 | print("SELECT 'Result set:';") 323 | print(f"SELECT * FROM {case_name};") 324 | if args.compare: 325 | print("SELECT 'Non expected records in result set:';") 326 | print(f"SELECT * FROM {case_name} EXCEPT SELECT * FROM test_expected;") 327 | print("SELECT 'Missing records in result set:';") 328 | print(f"SELECT * FROM test_expected EXCEPT SELECT * FROM {case_name};") 329 | 330 | 331 | def test_table_name(line): 332 | """Return the name of the table to use.""" 333 | matched = RE_DB_TABLESPEC.match(line) 334 | if matched is not None: 335 | return 'test_' + line[:-1] 336 | return line[:-1] 337 | 338 | 339 | def insert_values(table, types, line): 340 | """Insert into the table the specified values and their types coming 341 | from line""" 342 | 343 | values = shlex.split(line) 344 | quoted_list = ', '.join([t.get_value(v) for v, t in zip(values, types)]) 345 | print('INSERT INTO ' + table + ' VALUES (' + quoted_list + ');') 346 | 347 | 348 | def syntax_error(line_number, state, reason): 349 | """Terminate the program indicating a syntax error""" 350 | sys.exit(f"Syntax error on line {line_number}: {reason}" + 351 | f" (state: {state})") 352 | 353 | 354 | def file_to_list(file_input): 355 | """Convert file input into a list. This allows it to be processed 356 | multiple times.""" 357 | result = [] 358 | for line in file_input: 359 | result.append(line) 360 | return result 361 | 362 | 363 | def create_databases(dbengine, test_spec, created_databases): 364 | """Scan the file for the databases to create and update 365 | created_databases with their names""" 366 | for line in test_spec: 367 | matched = RE_DB_TABLESPEC.match(line) 368 | if matched is not None: 369 | create_database(dbengine, created_databases, 370 | 'test_' + matched.group(1)) 371 | 372 | 373 | def process_test(args, dbengine, test_name, test_spec): 374 | """Process the specified input stream. 375 | Return a regular expression matching constructed databases, 376 | when the postconditions line has been reached.""" 377 | # pylint: disable=too-many-statements 378 | # pylint: disable=too-many-branches 379 | # pylint: disable=too-many-locals 380 | state = 'initial' 381 | test_number = 1 382 | # Created databases 383 | created_databases = [] 384 | # To silence pylint 385 | table_created = False 386 | column_names = [] 387 | 388 | test_spec = file_to_list(test_spec) 389 | create_databases(dbengine, test_spec, created_databases) 390 | db_re = make_db_re(created_databases) 391 | line_number = 0 392 | for line in test_spec: 393 | line_number += 1 394 | line = line.rstrip() 395 | if line == '' or line[0] == '#': 396 | continue 397 | 398 | # Initial state 399 | if state == 'initial': 400 | print("\n-- " + line) 401 | if line == 'BEGIN SETUP': 402 | state = 'setup' 403 | table_name = None 404 | elif line == 'BEGIN CREATE': 405 | test_statement_type = 'create' 406 | state = 'sql' 407 | elif line == 'BEGIN SELECT': 408 | print('CREATE VIEW test_select_result AS') 409 | test_statement_type = 'select' 410 | state = 'sql' 411 | elif RE_INCLUDE_SELECT.match(line) is not None: 412 | matched = RE_INCLUDE_SELECT.match(line) 413 | dbengine.create_view('test_select_result') 414 | process_sql(matched.group(1), make_db_re(created_databases)) 415 | test_statement_type = 'select' 416 | elif RE_INCLUDE_CREATE.match(line) is not None: 417 | matched = RE_INCLUDE_CREATE.match(line) 418 | process_sql(matched.group(1), make_db_re(created_databases)) 419 | test_statement_type = 'create' 420 | elif line == 'BEGIN RESULT': 421 | if test_statement_type == 'select': 422 | # Directly process columns; table name is implicit 423 | table_name = 'test_select_result' 424 | state = 'table_columns' 425 | prev_state = 'result' 426 | elif test_statement_type == 'create': 427 | state = 'result' 428 | else: 429 | syntax_error(line_number, state, 430 | 'CREATE or SELECT not specified') 431 | test_statement_type = None 432 | else: 433 | syntax_error(line_number, state, 'Unknown statement: ' + line) 434 | 435 | # Table setup specifications 436 | elif state == 'setup': 437 | if line == 'END': 438 | state = 'initial' 439 | table_name = None 440 | continue 441 | # Table name 442 | if line[-1] == ':': 443 | table_name = test_table_name(line) 444 | state = 'table_columns' 445 | prev_state = 'setup' 446 | continue 447 | # Data 448 | if not table_created: 449 | if not table_name: 450 | syntax_error(line_number, state, 451 | 'Attempt to provide data ' + 452 | 'without specifying a table name') 453 | types = create_table(dbengine, table_name, column_names, line) 454 | table_created = True 455 | insert_values(table_name, types, line) 456 | 457 | # Embedded SQL code 458 | elif state == 'sql': 459 | line = line.rstrip() 460 | if line == 'END': 461 | state = 'initial' 462 | continue 463 | line = db_re.sub(r'test_\1.', line) 464 | print(line) 465 | 466 | # Specification of table columns 467 | elif state == 'table_columns': 468 | # Table column names 469 | column_names = line.split() 470 | state = prev_state 471 | table_created = False 472 | continue 473 | 474 | # Check a result 475 | elif state == 'result': 476 | if line == 'END': 477 | if not table_name: 478 | syntax_error(line_number, state, 479 | 'Attempt to provide data ' + 480 | 'without specifying a table name') 481 | if not table_created: 482 | types = create_table(dbengine, 'test_expected', 483 | column_names, 484 | ' '.join(column_names)) 485 | table_created = True 486 | verify_content(args, test_number, test_name, table_name) 487 | test_number += 1 488 | state = 'initial' 489 | continue 490 | # Table name 491 | if line[-1] == ':': 492 | table_name = test_table_name(line) 493 | state = 'table_columns' 494 | prev_state = 'result' 495 | continue 496 | # Data 497 | if not table_created: 498 | types = create_table(dbengine, 'test_expected', 499 | column_names, line) 500 | table_created = True 501 | insert_values('test_expected', types, line) 502 | else: 503 | sys.exit('Invalid state: ' + state) 504 | if state != 'initial': 505 | sys.exit('Unterminated state: ' + state) 506 | 507 | # Display number of executed test cases 508 | print(f"SELECT '1..{test_number - 1}';") 509 | 510 | 511 | def main(): 512 | """Program entry point: parse arguments and create test cases""" 513 | parser = argparse.ArgumentParser( 514 | description='Relational database query unity testing') 515 | parser.add_argument('-d', '--database', 516 | help='Database engine to use;' + 517 | 'one of sqlite, mysql, postgresql', default='mysql') 518 | 519 | parser.add_argument('-c', '--compare', 520 | help='Compare results of each test with expected ones', 521 | action='store_true') 522 | 523 | parser.add_argument('-e', '--existing-database', 524 | help='Use existing database; do not create test one', 525 | action='store_true') 526 | 527 | parser.add_argument('-r', '--results', 528 | help='Show the result of each test', 529 | action='store_true') 530 | 531 | parser.add_argument('test_script', 532 | help='Script containing test specification', 533 | nargs='*', default='-', 534 | type=str) 535 | args = parser.parse_args() 536 | print('-- Auto generated test script file from rdbunit') 537 | for script_name in args.test_script: 538 | if script_name == '-': 539 | create_test_cases(args, '', sys.stdin) 540 | else: 541 | with open(script_name, encoding="UTF-8") as test_input: 542 | create_test_cases(args, script_name, test_input) 543 | 544 | 545 | if __name__ == "__main__": 546 | main() 547 | -------------------------------------------------------------------------------- /tests/test-mysql.sh: -------------------------------------------------------------------------------- 1 | #!/bin/sh 2 | # 3 | # Test Rdbunit on MariaDB/mySQL 4 | # 5 | 6 | # Fail on command errors and unset variables 7 | set -eu 8 | 9 | # Run the tests 10 | cd examples 11 | ../src/rdbunit/__main__.py --database=mysql *.rdbu | 12 | if [ -n "${MYSQL_ROOT_PASSWORD:-}" ] ; then 13 | mysql -uroot -p"$MYSQL_ROOT_PASSWORD" -h 127.0.0.1 -P 3306 14 | else 15 | sudo mysql -N 16 | fi 17 | -------------------------------------------------------------------------------- /tests/test-parts.sh: -------------------------------------------------------------------------------- 1 | #!/bin/sh 2 | # 3 | # Verify that the script and the database work as expected 4 | # 5 | 6 | for i in simple datatypes ; do 7 | if ! src/rdbunit/__main__.py --database=sqlite -e "examples/$i.rdbu" >script.sql ; then 8 | echo "Script failed" 1>&2 9 | exit 1 10 | fi 11 | if ! sqlite3 script.out 2>&1 ; then 12 | echo "Sqlite execution failed" 1>&2 13 | echo "Input" 1>&2 14 | cat -n script.sql 1>&2 15 | echo "Output" 1>&2 16 | cat -n script.out 1>&2 17 | exit 1 18 | fi 19 | if egrep -v -e '^ok [0-9]' -e '^[0-9]+\.\.[0-9]+.?$' script.out ; then 20 | echo "Test failed or it produced extraneous output" 1>&2 21 | exit 1 22 | fi 23 | done 24 | 25 | rm script.sql script.out 26 | -------------------------------------------------------------------------------- /tests/test-postgresql.sh: -------------------------------------------------------------------------------- 1 | #!/bin/sh 2 | # 3 | # Test Rdbunit on PostgreSQL 4 | # 5 | 6 | # Fail on command errors and unset variables 7 | set -eu 8 | 9 | if [ -z "${POSTGRES_USER:-}" ] ; then 10 | export PGPASSWORD=$(openssl rand -base64 21) 11 | 12 | # Setup a PostgreSQL database for testing Rdbunit 13 | cat </dev/null 14 | DROP DATABASE IF EXISTS rdbunit_db; 15 | DROP ROLE IF EXISTS rdbunit_user; 16 | CREATE DATABASE rdbunit_db; 17 | CREATE USER rdbunit_user; 18 | GRANT ALL PRIVILEGES ON DATABASE rdbunit_db TO rdbunit_user; 19 | ALTER USER rdbunit_user WITH PASSWORD '$PGPASSWORD'; 20 | EOF 21 | fi 22 | 23 | 24 | # Run the tests 25 | cd examples 26 | for i in *.rdbu ; do 27 | ../src/rdbunit/__main__.py --database=postgresql $i | 28 | if [ -n "${POSTGRES_USER:-}" ] ; then 29 | psql -U "$POSTGRES_USER" -h 127.0.0.1 -p 5432 -t -q 30 | else 31 | psql -U rdbunit_user -d rdbunit_db -h localhost -t -q 32 | fi 33 | done 34 | -------------------------------------------------------------------------------- /tests/test-sqlite.sh: -------------------------------------------------------------------------------- 1 | #!/bin/sh 2 | # 3 | # Test Rdbunit on SQLite 4 | # 5 | 6 | # Fail on command errors and unset variables 7 | set -eu 8 | 9 | # Run the tests 10 | cd examples 11 | for i in *.rdbu ; do 12 | ../src/rdbunit/__main__.py --database=sqlite $i | 13 | sqlite3 14 | done 15 | --------------------------------------------------------------------------------