|
| 1 | +# QueryBuilder python module |
| 2 | + |
| 3 | +     |
| 4 | + |
| 5 | +This is a small easy-to-use component for working with a database. It provides some public methods to compose SQL queries and manipulate data. Each SQL query is prepared and safe. QueryBuilder fetches data to _list_ by default. At present time the component supports SQLite (file or memory). |
| 6 | + |
| 7 | +## Contributing |
| 8 | + |
| 9 | +Bug reports and/or pull requests are welcome |
| 10 | + |
| 11 | +## License |
| 12 | + |
| 13 | +The module is available as open source under the terms of the [MIT](https://github.com/co0lc0der/simple-query-builder-python/blob/main/LICENSE.md) |
| 14 | + |
| 15 | +## Installation |
| 16 | + |
| 17 | +Install the current version with [PyPI](https://pypi.org/project/simple-query-builder): |
| 18 | + |
| 19 | +```bash |
| 20 | +pip install simple-query-builder |
| 21 | +``` |
| 22 | + |
| 23 | +Or from Github: |
| 24 | +```bash |
| 25 | +pip install https://github.com/co0lc0der/simple-query-builder-python/archive/main.zip |
| 26 | +``` |
| 27 | +## How to use |
| 28 | +### Main public methods |
| 29 | +- `get_sql()` returns SQL query string which will be executed |
| 30 | +- `get_params()` returns an array of parameters for a query |
| 31 | +- `get_result()` returns query's results |
| 32 | +- `get_count()` returns results' rows count |
| 33 | +- `get_error()` returns `True` if an error is had |
| 34 | +- `get_error_message()` returns an error message if an error is had |
| 35 | +- `set_error(message)` sets `_error` to `True` and `_error_essage` |
| 36 | +- `get_first()` returns the first item of results |
| 37 | +- `get_last()` returns the last item of results |
| 38 | +- `reset()` resets state to default values (except PDO property) |
| 39 | +- `all()` executes SQL query and return all rows of result (`fetchall()`) |
| 40 | +- `one()` executes SQL query and return the first row of result (`fetchone()`) |
| 41 | +- `column(col_index)` executes SQL query and return the first column of result, `col_index` is `0` by default |
| 42 | +- `go()` this method is for non `SELECT` queries. it executes SQL query and return nothing (but returns the last inserted row ID for `INSERT` method) |
| 43 | +- `count()` prepares a query with SQL `COUNT()` function |
| 44 | +- `query(sql, params, fetch_type, col_index)` executes prepared `sql` with `params`, it can be used for custom queries |
| 45 | +- 'SQL' methods are presented in [Usage section](#usage-examples) |
| 46 | + |
| 47 | +### Import the module and init `QueryBuilder` with `Database()` |
| 48 | +```python |
| 49 | +from querybuilder import * |
| 50 | + |
| 51 | +qb = QueryBuilder(DataBase(), 'my_db.db') |
| 52 | +``` |
| 53 | +### Usage examples |
| 54 | +- Select all rows from a table |
| 55 | +```python |
| 56 | +results = qb.select('users').all() |
| 57 | +``` |
| 58 | +```sql |
| 59 | +SELECT * FROM `users`; |
| 60 | +``` |
| 61 | +- Select a row with a condition |
| 62 | +```python |
| 63 | +results = qb.select('users').where([['id', '=', 10]]).one() |
| 64 | +``` |
| 65 | +```sql |
| 66 | +SELECT * FROM `users` WHERE `id` = 10; |
| 67 | +``` |
| 68 | +- Select rows with two conditions |
| 69 | +```python |
| 70 | +results = qb.select('users')\ |
| 71 | + .where([['id', '>', 1], 'and', ['group_id', '=', 2]])\ |
| 72 | + .all() |
| 73 | +``` |
| 74 | +```sql |
| 75 | +SELECT * FROM `users` WHERE (`id` > 1) AND (`group_id` = 2) |
| 76 | +``` |
| 77 | +- Select a row with a `LIKE` and `NOT LIKE` condition |
| 78 | +```python |
| 79 | +results = qb.select('users').like(['name', '%John%']).all() |
| 80 | +# or |
| 81 | +results = qb.select('users').where([['name', 'LIKE', '%John%']]).all() |
| 82 | +``` |
| 83 | +```sql |
| 84 | +SELECT * FROM `users` WHERE (`name` LIKE '%John%') |
| 85 | +``` |
| 86 | +```python |
| 87 | +results = qb.select('users').notLike(['name', '%John%']).all() |
| 88 | +# or |
| 89 | +results = qb.select('users').where([['name', 'NOT LIKE', '%John%']]).all() |
| 90 | +``` |
| 91 | +```sql |
| 92 | +SELECT * FROM `users` WHERE (`name` NOT LIKE '%John%') |
| 93 | +``` |
| 94 | +- Select rows with `OFFSET` and `LIMIT` |
| 95 | +```python |
| 96 | +results = qb.select('posts')\ |
| 97 | + .where([['user_id', '=', 3]])\ |
| 98 | + .offset(14)\ |
| 99 | + .limit(7)\ |
| 100 | + .all() |
| 101 | +``` |
| 102 | +```sql |
| 103 | +SELECT * FROM `posts` WHERE (`user_id` = 3) OFFSET 14 LIMIT 7; |
| 104 | +``` |
| 105 | +- Select custom fields with additional SQL |
| 106 | +1. `COUNT()` |
| 107 | +```python |
| 108 | +results = qb.select('users', {'counter': 'COUNT(*)'}).one() |
| 109 | +# or |
| 110 | +results = qb.count('users').one() |
| 111 | +``` |
| 112 | +```sql |
| 113 | +SELECT COUNT(*) AS `counter` FROM `users`; |
| 114 | +``` |
| 115 | +2. `ORDER BY` |
| 116 | +```python |
| 117 | +results = qb.select({'b': 'branches'}, ['b.id', 'b.name'])\ |
| 118 | + .where([['b.id', '>', 1], 'and', ['b.parent_id', '=', 1]])\ |
| 119 | + .orderBy('b.id', 'desc')\ |
| 120 | + .all() |
| 121 | +``` |
| 122 | +```sql |
| 123 | +SELECT `b`.`id`, `b`.`name` FROM `branches` AS `b` |
| 124 | +WHERE (`b`.`id` > 1) AND (`b`.`parent_id` = 1) |
| 125 | +ORDER BY `b`.`id` DESC; |
| 126 | +``` |
| 127 | +3. `GROUP BY` and `HAVING` |
| 128 | +```python |
| 129 | +results = qb.select('posts', ['id', 'category', 'title'])\ |
| 130 | + .where([['views', '>=', 1000]])\ |
| 131 | + .groupBy('category')\ |
| 132 | + .all() |
| 133 | +``` |
| 134 | +```sql |
| 135 | +SELECT `id`, `category`, `title` FROM `posts` |
| 136 | +WHERE (`views` >= 1000) GROUP BY `category`; |
| 137 | +``` |
| 138 | +```python |
| 139 | +groups = qb.select('orders', {'month_num': 'MONTH(`created_at`)', 'total': 'SUM(`total`)'})\ |
| 140 | + .where([['YEAR(`created_at`)', '=', 2020]])\ |
| 141 | + .groupBy('month_num')\ |
| 142 | + .having([['total', '>', 20000]])\ |
| 143 | + .all() |
| 144 | +``` |
| 145 | +```sql |
| 146 | +SELECT MONTH(`created_at`) AS `month_num`, SUM(`total`) AS `total` |
| 147 | +FROM `orders` WHERE (YEAR(`created_at`) = 2020) |
| 148 | +GROUP BY `month_num` HAVING (`total` > 20000) |
| 149 | +``` |
| 150 | +4. `JOIN`. Supports `INNER`, `LEFT OUTER`, `RIGHT OUTER`, `FULL OUTER` and `CROSS` joins (`INNER` is by default) |
| 151 | +```python |
| 152 | +results = qb.select({'u': 'users'}, [ |
| 153 | + 'u.id', |
| 154 | + 'u.email', |
| 155 | + 'u.username', |
| 156 | + {'perms': 'groups.permissions'} |
| 157 | + ])\ |
| 158 | + .join('groups', ['u.group_id', 'groups.id'])\ |
| 159 | + .limit(5)\ |
| 160 | + .all() |
| 161 | +``` |
| 162 | +```sql |
| 163 | +SELECT `u`.`id`, `u`.`email`, `u`.`username`, `groups`.`permissions` AS `perms` |
| 164 | +FROM `users` AS `u` |
| 165 | +INNER JOIN `groups` ON `u`.`group_id` = `groups`.`id` |
| 166 | +LIMIT 5; |
| 167 | +``` |
| 168 | +```python |
| 169 | +results = qb.select({'cp': 'cabs_printers'}, [ |
| 170 | + 'cp.id', |
| 171 | + 'cp.cab_id', |
| 172 | + {'cab_name': 'cb.name'}, |
| 173 | + 'cp.printer_id', |
| 174 | + {'printer_name': 'p.name'}, |
| 175 | + {'cartridge_type': 'c.name'}, |
| 176 | + 'cp.comment' |
| 177 | + ])\ |
| 178 | + .join({'cb': 'cabs'}, ['cp.cab_id', 'cb.id'])\ |
| 179 | + .join({'p': 'printer_models'}, ['cp.printer_id', 'p.id'])\ |
| 180 | + .join({'c': 'cartridge_types'}, 'p.cartridge_id=c.id')\ |
| 181 | + .where([['cp.cab_id', 'in', [11, 12, 13]], 'or', ['cp.cab_id', '=', 5], 'and', ['p.id', '>', 'c.id']])\ |
| 182 | + .all() |
| 183 | +``` |
| 184 | +```sql |
| 185 | +SELECT `cp`.`id`, `cp`.`cab_id`, `cb`.`name` AS `cab_name`, `cp`.`printer_id`, |
| 186 | + `p`.`name` AS `printer_name`, `c`.`name` AS `cartridge_type`, `cp`.`comment` |
| 187 | +FROM `cabs_printers` AS `cp` |
| 188 | +INNER JOIN `cabs` AS `cb` ON `cp`.`cab_id` = `cb`.`id` |
| 189 | +INNER JOIN `printer_models` AS `p` ON `cp`.`printer_id` = `p`.`id` |
| 190 | +INNER JOIN `cartridge_types` AS `c` ON p.cartridge_id=c.id |
| 191 | +WHERE (`cp`.`cab_id` IN (11,12,13)) OR (`cp`.`cab_id` = 5) AND (`p`.`id` > `c`.`id`) |
| 192 | +``` |
| 193 | +- Insert a row |
| 194 | +```python |
| 195 | +new_id = qb.insert('groups', { |
| 196 | + 'name': 'Moderator', |
| 197 | + 'permissions': 'moderator' |
| 198 | +}).go() |
| 199 | +``` |
| 200 | +```sql |
| 201 | +INSERT INTO `groups` (`name`, `permissions`) VALUES ('Moderator', 'moderator') |
| 202 | +``` |
| 203 | +- Insert many rows |
| 204 | +```python |
| 205 | +qb.insert('groups', [['name', 'role'], |
| 206 | + ['Moderator', 'moderator'], |
| 207 | + ['Moderator2', 'moderator'], |
| 208 | + ['User', 'user'], |
| 209 | + ['User2', 'user'] |
| 210 | +]).go() |
| 211 | +``` |
| 212 | +```sql |
| 213 | +INSERT INTO `groups` (`name`, `role`) |
| 214 | +VALUES ('Moderator', 'moderator'), |
| 215 | + ('Moderator2', 'moderator'), |
| 216 | + ('User', 'user'), |
| 217 | + ('User2', 'user') |
| 218 | +``` |
| 219 | +- Update a row |
| 220 | +```python |
| 221 | +qb.update('users', { |
| 222 | + 'username': 'John Doe', |
| 223 | + 'status': 'new status' |
| 224 | + })\ |
| 225 | + .where([['id', '=', 7]])\ |
| 226 | + .limit()\ |
| 227 | + .go() |
| 228 | +``` |
| 229 | +```sql |
| 230 | +UPDATE `users` SET `username` = 'John Doe', `status` = 'new status' |
| 231 | +WHERE `id` = 7 LIMIT 1; |
| 232 | +``` |
| 233 | +- Update rows |
| 234 | +```python |
| 235 | +qb.update('posts', {'status': 'published'})\ |
| 236 | + .where([['YEAR(`updated_at`)', '>', 2020]])\ |
| 237 | + .go() |
| 238 | +``` |
| 239 | +```sql |
| 240 | +UPDATE `posts` SET `status` = 'published' |
| 241 | +WHERE (YEAR(`updated_at`) > 2020) |
| 242 | +``` |
| 243 | +- Delete a row |
| 244 | +```python |
| 245 | +qb.delete('users')\ |
| 246 | + .where([['name', '=', 'John']])\ |
| 247 | + .limit()\ |
| 248 | + .go() |
| 249 | +``` |
| 250 | +```sql |
| 251 | +DELETE FROM `users` WHERE `name` = 'John' LIMIT 1; |
| 252 | +``` |
| 253 | +- Delete rows |
| 254 | +```python |
| 255 | +qb.delete('comments')\ |
| 256 | + .where([['user_id', '=', 10]])\ |
| 257 | + .go() |
| 258 | +``` |
| 259 | +```sql |
| 260 | +DELETE FROM `comments` WHERE `user_id` = 10; |
| 261 | +``` |
| 262 | +- Truncate a table |
| 263 | +```python |
| 264 | +qb.truncate('users').go() |
| 265 | +``` |
| 266 | +```sql |
| 267 | +TRUNCATE TABLE `users`; |
| 268 | +``` |
| 269 | +- Drop a table |
| 270 | +```python |
| 271 | +qb.drop('temporary').go() |
| 272 | +``` |
| 273 | +```sql |
| 274 | +DROP TABLE IF EXISTS `temporary`; |
| 275 | +``` |
0 commit comments