├── .cs.php
├── .editorconfig
├── .gitattributes
├── .github
└── workflows
│ └── build.yml
├── .gitignore
├── .scrutinizer.yml
├── LICENSE
├── README.md
├── composer.json
├── docs
├── _config.yml
├── connection.md
├── deletes.md
├── gemfile
├── index.md
├── inserts.md
├── selects.md
├── slim.md
└── updates.md
├── phpcs.xml
├── phpstan.neon
├── phpunit.xml
├── src
├── Condition.php
├── Connection.php
├── DatabaseException.php
├── DeleteQuery.php
├── FunctionBuilder.php
├── FunctionExpression.php
├── InsertQuery.php
├── Operator.php
├── QueryInterface.php
├── Quoter.php
├── RawExp.php
├── SelectQuery.php
├── SelectQueryBuilder.php
└── UpdateQuery.php
└── tests
├── BaseTest.php
├── ConnectionTest.php
├── DeleteQueryTest.php
├── FunctionBuilderTest.php
├── InsertQueryTest.php
├── QuoterTest.php
├── RawExpTest.php
├── SelectQueryTest.php
└── UpdateQueryTest.php
/.cs.php:
--------------------------------------------------------------------------------
1 | setUsingCache(false)
7 | ->setRiskyAllowed(true)
8 | ->setRules(
9 | [
10 | '@PSR1' => true,
11 | '@PSR2' => true,
12 | '@Symfony' => true,
13 | 'psr_autoloading' => true,
14 | // custom rules
15 | 'align_multiline_comment' => ['comment_type' => 'phpdocs_only'], // psr-5
16 | 'phpdoc_to_comment' => false,
17 | 'no_superfluous_phpdoc_tags' => false,
18 | 'array_indentation' => true,
19 | 'array_syntax' => ['syntax' => 'short'],
20 | 'cast_spaces' => ['space' => 'none'],
21 | 'concat_space' => ['spacing' => 'one'],
22 | 'compact_nullable_typehint' => true,
23 | 'declare_equal_normalize' => ['space' => 'single'],
24 | 'increment_style' => ['style' => 'post'],
25 | 'list_syntax' => ['syntax' => 'short'],
26 | 'echo_tag_syntax' => ['format' => 'long'],
27 | 'phpdoc_add_missing_param_annotation' => ['only_untyped' => false],
28 | 'phpdoc_align' => false,
29 | 'phpdoc_no_empty_return' => false,
30 | 'phpdoc_order' => true, // psr-5
31 | 'phpdoc_no_useless_inheritdoc' => false,
32 | 'protected_to_private' => false,
33 | 'yoda_style' => false,
34 | 'method_argument_space' => ['on_multiline' => 'ensure_fully_multiline'],
35 | 'ordered_imports' => [
36 | 'sort_algorithm' => 'alpha',
37 | 'imports_order' => ['class', 'const', 'function']
38 | ],
39 | 'single_line_throw' => false,
40 | 'fully_qualified_strict_types' => true,
41 | 'global_namespace_import' => false,
42 | ]
43 | )
44 | ->setFinder(
45 | PhpCsFixer\Finder::create()
46 | ->in(__DIR__ . '/src')
47 | ->in(__DIR__ . '/tests')
48 | ->name('*.php')
49 | ->ignoreDotFiles(true)
50 | ->ignoreVCS(true)
51 | );
52 |
--------------------------------------------------------------------------------
/.editorconfig:
--------------------------------------------------------------------------------
1 | # This file is for unifying the coding style for different editors and IDEs.
2 | # More information at http://editorconfig.org
3 |
4 | root = true
5 |
6 | [*]
7 | charset = utf-8
8 | indent_style = space
9 | indent_size = 4
10 | end_of_line = lf
11 | insert_final_newline = true
12 | trim_trailing_whitespace = true
13 |
14 | [*.yml]
15 | indent_size = 2
16 |
--------------------------------------------------------------------------------
/.gitattributes:
--------------------------------------------------------------------------------
1 | public/* linguist-vendored
2 | docs/* linguist-documentation
3 |
4 | # Set the default behavior, in case people don't have core.autocrlf set.
5 | # Git will always convert line endings to LF on checkout. You should use
6 | # this for files that must keep LF endings, even on Windows.
7 | * text eol=lf
8 |
9 | # Define binary file attributes.
10 | # - Do not treat them as text.
11 | # - Include binary diff in patches instead of "binary files differ."
12 | *.gif binary
13 | *.ico binary
14 | *.jpg binary
15 | *.png binary
16 | *.phar binary
17 | *.zip binary
18 | *.gz binary
19 | *.otf binary
20 | *.eot binary
21 | *.svg binary
22 | *.ttf binary
23 | *.woff binary
24 | *.woff2 binary
25 |
26 | # ------------------------------------------------------------------------------
27 | # All the files and directories that can be excluded from dist,
28 | # we could have a more clean vendor/
29 | #
30 | # So when someone will install that package through with --prefer-dist option,
31 | # all the files and directories listed in .gitattributes file will be excluded.
32 | # This could have a big impact on big deployments and/or testing.
33 | # ------------------------------------------------------------------------------
34 |
35 |
--------------------------------------------------------------------------------
/.github/workflows/build.yml:
--------------------------------------------------------------------------------
1 | name: build
2 |
3 | on: [ push, pull_request ]
4 |
5 | jobs:
6 | run:
7 | runs-on: ${{ matrix.operating-system }}
8 | strategy:
9 | matrix:
10 | operating-system: [ ubuntu-latest ]
11 | php-versions: [ '8.1' ]
12 | name: PHP ${{ matrix.php-versions }} Test on ${{ matrix.operating-system }}
13 |
14 | services:
15 | mysql:
16 | image: mysql:8.0.23
17 | env:
18 | MYSQL_ROOT_PASSWORD: root
19 | MYSQL_DATABASE: test
20 | MYSQL_ALLOW_EMPTY_PASSWORD: true
21 | ports:
22 | - 33306:3306
23 |
24 | steps:
25 | - name: Checkout
26 | uses: actions/checkout@v1
27 |
28 | - name: Setup PHP
29 | uses: shivammathur/setup-php@v2
30 | with:
31 | php-version: ${{ matrix.php-versions }}
32 | extensions: mbstring, pdo, pdo_mysql, intl, zip
33 | coverage: none
34 |
35 | - name: Check PHP version
36 | run: php -v
37 |
38 | - name: Check Composer version
39 | run: composer -V
40 |
41 | - name: Check PHP extensions
42 | run: php -m
43 |
44 | - name: Check MySQL version
45 | run: mysql -V
46 |
47 | - name: Start MySQL
48 | run: sudo systemctl start mysql
49 |
50 | - name: Create database
51 | run: mysql -uroot -proot -e 'CREATE DATABASE IF NOT EXISTS database_test CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;'
52 |
53 | - name: Validate composer.json and composer.lock
54 | run: composer validate
55 |
56 | - name: Install dependencies
57 | run: composer install --prefer-dist --no-progress --no-suggest
58 |
59 | - name: Run test suite
60 | run: composer test:all
61 | env:
62 | PHP_CS_FIXER_IGNORE_ENV: 1
63 |
--------------------------------------------------------------------------------
/.gitignore:
--------------------------------------------------------------------------------
1 | nbproject/
2 | .idea/
3 | composer.phar
4 | composer.lock
5 | .DS_STORE
6 | cache.properties
7 | .php_cs.cache
8 | .vscode
9 |
10 | .env
11 | env.php
12 | config/env.php
13 |
14 | !public/cache/
15 | public/cache/*
16 | !public/cache/.htaccess
17 |
18 | !tmp/
19 | tmp/*
20 | !tmp/.htaccess
21 |
22 | !tmp/log/
23 | tmp/log/*
24 | !tmp/log/empty
25 |
26 | !tmp/cache/
27 | tmp/cache/*
28 | !tmp/cache/empty
29 |
30 | vendor/
31 | build/
32 |
--------------------------------------------------------------------------------
/.scrutinizer.yml:
--------------------------------------------------------------------------------
1 | filter:
2 | paths: [ "src/*" ]
3 | excluded_paths: [ "vendor/*", "tests/*" ]
4 |
5 | checks:
6 | php:
7 | code_rating: true
8 | duplication: true
9 |
10 | tools:
11 | external_code_coverage: false
12 |
13 | build:
14 | services:
15 | mysql: 5.7
16 | environment:
17 | php:
18 | version: 8.1.2
19 | ini:
20 | xdebug.mode: coverage
21 | mysql: 5.7
22 | node: false
23 | postgresql: false
24 | mongodb: false
25 | elasticsearch: false
26 | redis: false
27 | memcached: false
28 | neo4j: false
29 | rabbitmq: false
30 | nodes:
31 | analysis:
32 | tests:
33 | override:
34 | - php-scrutinizer-run
35 | dependencies:
36 | before:
37 | - composer self-update
38 | - composer install --no-interaction --prefer-dist --no-progress
39 | - mysql -u root -e "CREATE DATABASE IF NOT EXISTS database_test CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;"
40 | tests:
41 | before:
42 | - command: composer test:coverage
43 | coverage:
44 | file: 'build/logs/clover.xml'
45 | format: 'clover'
46 |
--------------------------------------------------------------------------------
/LICENSE:
--------------------------------------------------------------------------------
1 | The MIT License (MIT)
2 |
3 | Copyright (c) 2023 odan
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 | # Database
2 |
3 | A fluent SQL query builder.
4 |
5 | [](https://packagist.org/packages/selective/database)
6 | [](LICENSE)
7 | [](https://github.com/selective-php/database/actions)
8 | [](https://scrutinizer-ci.com/g/selective-php/database/code-structure)
9 | [](https://scrutinizer-ci.com/g/selective-php/database/?branch=master)
10 | [](https://packagist.org/packages/selective/database/stats)
11 |
12 | ## Features
13 |
14 | * Fluent SQL query builder
15 | * Table schema information and manipulation
16 |
17 | ## Installation
18 |
19 | ```
20 | composer require selective/database
21 | ```
22 |
23 | ## Requirements
24 |
25 | * PHP 8.0+
26 | * MySQL 5.7+ or MariaDB
27 |
28 | ## Documentation
29 |
30 | The database query builder provides a convenient, fluent interface for creating and executing database queries. It can be used to perform most database operations in your PHP website and application.
31 |
32 | For more details how to build queries please read the **[documentation](https://selective-php.github.io/database/)**.
33 |
34 | ## Similar libraries
35 |
36 | * [cycle/database](https://cycle-orm.dev/docs/query-builder-basic)
37 | * [cakephp/database](https://github.com/cakephp/database)
38 | * [laminas/laminas-db](https://docs.laminas.dev/laminas-db/)
39 |
40 | ## License
41 |
42 | The MIT License (MIT). Please see [License File](LICENSE) for more information.
43 |
--------------------------------------------------------------------------------
/composer.json:
--------------------------------------------------------------------------------
1 | {
2 | "name": "selective/database",
3 | "type": "library",
4 | "description": "SQL query builder",
5 | "keywords": [
6 | "sql",
7 | "mysql",
8 | "query",
9 | "builder",
10 | "database"
11 | ],
12 | "homepage": "https://github.com/selective-php/database",
13 | "license": "MIT",
14 | "require-dev": {
15 | "friendsofphp/php-cs-fixer": "^3",
16 | "phpstan/phpstan": "^1",
17 | "phpunit/phpunit": "^9 || ^10",
18 | "squizlabs/php_codesniffer": "^3"
19 | },
20 | "require": {
21 | "php": "^8.0",
22 | "ext-pdo": "*"
23 | },
24 | "autoload": {
25 | "psr-4": {
26 | "Selective\\Database\\": "src/"
27 | }
28 | },
29 | "autoload-dev": {
30 | "psr-4": {
31 | "Selective\\Database\\Test\\": "tests/"
32 | }
33 | },
34 | "config": {
35 | "sort-packages": true,
36 | "process-timeout": 0
37 | },
38 | "scripts": {
39 | "cs:check": "php-cs-fixer fix --dry-run --format=txt --verbose --diff --config=.cs.php --ansi",
40 | "cs:fix": "php-cs-fixer fix --config=.cs.php --ansi",
41 | "sniffer:check": "phpcs --standard=phpcs.xml",
42 | "sniffer:fix": "phpcbf --standard=phpcs.xml",
43 | "stan": "phpstan analyse -c phpstan.neon --no-progress --ansi --xdebug",
44 | "test": "phpunit --configuration phpunit.xml --do-not-cache-result --colors=always",
45 | "test:all": [
46 | "@cs:check",
47 | "@sniffer:check",
48 | "@stan",
49 | "@test"
50 | ],
51 | "test:coverage": "php -d xdebug.mode=coverage -r \"require 'vendor/bin/phpunit';\" -- --configuration phpunit.xml --do-not-cache-result --colors=always --coverage-clover build/logs/clover.xml --coverage-html build/coverage"
52 | }
53 | }
54 |
--------------------------------------------------------------------------------
/docs/_config.yml:
--------------------------------------------------------------------------------
1 | plugins:
2 | - jekyll-include-cache
3 |
4 | remote_theme: "pmarsceill/just-the-docs"
5 |
6 | # Name of your site (displayed in the header)
7 | name: Database
8 |
9 | # Name of website (site.title)
10 | title: Database
11 |
12 | # Short description of your site
13 | description: A SQL query builder
14 |
--------------------------------------------------------------------------------
/docs/connection.md:
--------------------------------------------------------------------------------
1 | ---
2 | layout: default
3 | title: Connection
4 | nav_order: 2
5 | ---
6 |
7 | # Connection
8 |
9 | Create a new database connection:
10 |
11 | ```php
12 | PDO::ERRMODE_EXCEPTION,
27 | PDO::ATTR_PERSISTENT => false,
28 | PDO::ATTR_DEFAULT_FETCH_MODE => PDO::FETCH_ASSOC,
29 | PDO::MYSQL_ATTR_INIT_COMMAND => "SET NAMES $charset COLLATE $collate"
30 | ];
31 |
32 | $pdo = new PDO($dsn, $username, $password, $options);
33 |
34 | $connection = new Connection($pdo);
35 | ```
36 |
37 | **Next page:** [Select](selects.md)
38 |
--------------------------------------------------------------------------------
/docs/deletes.md:
--------------------------------------------------------------------------------
1 | ---
2 | layout: default
3 | title: Deletes
4 | nav_order: 6
5 | ---
6 |
7 |
8 | ## Deletes
9 |
10 | Create a delete object:
11 |
12 | ```php
13 | use Selective\Database\Connection;
14 |
15 | $connection = new Connection($dsn, $username, $password, $options);
16 | $delete = $connection->delete();
17 | ```
18 |
19 | The query builder may also be used to delete records from the
20 | table via the delete method. You may constrain delete
21 | statements by adding where clauses before calling the delete method:
22 |
23 |
24 | ```php
25 | // DELETE FROM `users`
26 | $connection->delete()->from('users')->execute();
27 |
28 | // DELETE FROM `users` WHERE `votes` > '100'
29 | $connection->delete()->from('users')->where('votes', '>', 100)->execute();
30 | ```
31 |
32 | If you wish to truncate the entire table, which will remove
33 | all rows and reset the auto-incrementing ID to zero,
34 | you may use the truncate method:
35 |
36 | ```php
37 | // TRUNCATE TABLE `users`
38 | $connection->delete()
39 | ->from('users')
40 | ->truncate()
41 | ->execute();
42 | ```
43 |
44 | ### Order of Deletion
45 |
46 | If the DELETE statement includes an ORDER BY clause, rows are deleted in the
47 | order specified by the clause. This is useful primarily in conjunction with LIMIT.
48 |
49 | ```php
50 | $connection->delete()
51 | ->from('some_logs')
52 | ->where('username', '=', 'jcole')
53 | ->orderBy('created_at')
54 | ->limit(1)
55 | ->execute();
56 | ```
57 |
58 | ORDER BY also helps to delete rows in an order required to avoid referential integrity violations.
59 |
60 | ### Delete Limit
61 |
62 | The LIMIT clause places a limit on the number of rows that can be deleted.
63 |
64 | ```php
65 | $connection->delete()
66 | ->from('users')
67 | ->limit(10)
68 | ->execute();
69 | ```
70 |
71 | ### Delete Low Priority
72 |
73 | If you specify `LOW_PRIORITY`, the server delays execution of the
74 | DELETE until no other clients are reading from the table.
75 |
76 | This affects only storage engines that use only table-level
77 | locking (such as MyISAM, MEMORY, and MERGE).
78 |
79 | ```php
80 | $connection->delete()
81 | ->from('users')
82 | ->lowPriority()
83 | ->execute();
84 | ```
85 |
86 | ### Delete and ignore errors
87 |
88 | The `IGNORE` modifier causes MySQL to ignore errors during the process of deleting rows.
89 |
90 | (Errors encountered during the parsing stage are processed in the usual manner.)
91 |
92 | Errors that are ignored due to the use of IGNORE are returned as warnings.
93 |
94 | ```php
95 | $connection->delete()
96 | ->from('users')
97 | ->ignore()
98 | ->execute();
99 | ```
100 |
101 | ### Delete Quick modifier
102 |
103 | For MyISAM tables, if you use the QUICK modifier, the storage engine
104 | does not merge index leaves during delete, which may speed up some kinds of delete operations.
105 |
106 | ```php
107 | $connection->delete()
108 | ->from('users')
109 | ->quick()
110 | ->execute();
111 | ```
112 |
--------------------------------------------------------------------------------
/docs/gemfile:
--------------------------------------------------------------------------------
1 | source "https://rubygems.org"
2 |
3 | gem "github-pages", group: :jekyll_plugins
4 | gem "just-the-docs"
5 |
--------------------------------------------------------------------------------
/docs/index.md:
--------------------------------------------------------------------------------
1 | ---
2 | layout: default
3 | title: Home
4 | nav_order: 1
5 | description: "Database"
6 | ---
7 |
8 | # Documentation
9 |
10 | ## Introduction
11 |
12 | The database query builder provides a convenient, fluent interface for creating and executing database queries.
13 | It can be used to perform most database operations in your application and works on all supported database systems (MySql).
14 |
15 | The query builder uses quoting to protect your application against SQL injection attacks.
16 |
17 | ## Installation
18 |
19 | Install the component with Composer:
20 |
21 | ```shell
22 | composer require selective/database
23 | ```
24 |
25 | ## What's next
26 |
27 | * Read about how to create an [Connection](connection.md) object to build queries with it.
28 |
29 | ## Framework integration
30 |
31 | * [Slim 4](slim.md)
32 |
33 | **Next page:** [Connection](connection.md)
34 |
--------------------------------------------------------------------------------
/docs/inserts.md:
--------------------------------------------------------------------------------
1 | ---
2 | layout: default
3 | title: Inserts
4 | nav_order: 4
5 | ---
6 |
7 | ## Inserts
8 |
9 | Create an insert object:
10 |
11 | ```php
12 | use Selective\Database\Connection;
13 |
14 | $connection = new Connection($dsn, $username, $password, $options);
15 | $query = $connection->insert();
16 | ```
17 |
18 | ### Insert A Single Row
19 |
20 | The query builder also provides an insert method for inserting
21 | records into the database table.
22 |
23 | The insert method accepts an array of column names and values:
24 |
25 | ```php
26 | $connection->insert()
27 | ->into('test')
28 | ->set(['email' => 'john@example.com', 'votes' => 0])
29 | ->execute();
30 | ```
31 |
32 | You may even insert several records into the table with a single call
33 | to insert by passing an array of arrays. Each array represents a
34 | row to be inserted into the table:
35 |
36 | ```php
37 | $connection->insert()
38 | ->into('test')->set([
39 | ['email' => 'daniel@example.com', 'votes' => 0],
40 | ['email' => 'john@example.com', 'votes' => 0]
41 | ])->execute();
42 | ```
43 |
44 | ### Auto-Incrementing IDs
45 |
46 | If the table has an auto-incrementing id,
47 | use the insertGetId method to insert a record and then retrieve the ID:
48 |
49 | ```php
50 | $userId = $connection->insert()
51 | ->into('users')
52 | ->insertGetId(['email' => 'john@example.com', 'votes' => 0]);
53 | ```
54 |
55 | Another way to get the last inserted ID:
56 |
57 | ```php
58 | $connection->insert()
59 | ->into('users')
60 | ->set(['email' => 'john@example.com', 'votes' => 0])
61 | ->execute();
62 |
63 | $userId = $connection->lastInsertId();
64 | ```
65 |
66 | ### Number of rows affected by the last statement
67 |
68 | Sometimes you need more then just the last inserted ID, for example the number of affected rows.
69 | You can find this information in the Statement object:
70 |
71 | ```php
72 | $stmt = $connection->insert()
73 | ->into('users')
74 | ->set(['email' => 'john@example.com', 'votes' => 0])
75 | ->prepare();
76 |
77 | $stmt->execute();
78 | $rowCount = $stmt->rowCount(); // 1
79 | ```
80 |
81 | **Next page:** [Updates](updates.md)
82 |
--------------------------------------------------------------------------------
/docs/selects.md:
--------------------------------------------------------------------------------
1 | ---
2 | layout: default
3 | title: Selects
4 | nav_order: 3
5 | ---
6 |
7 | ## Selects
8 |
9 | Create a select query object with the connection object.
10 |
11 | ```php
12 | use Selective\Database\Connection;
13 |
14 | $connection = new Connection($pdo);
15 |
16 | $query = $connection->select();
17 | ```
18 |
19 | Creating a SelectQuery object manually:
20 |
21 | ```php
22 | use Selective\Database\Connection;
23 |
24 | $connection = new Connection($pdo);
25 |
26 | $query = new \Selective\Database\SelectQuery($connection);
27 | ```
28 |
29 | ## Inspecting The Query
30 |
31 | Getting the generated SQL string:
32 |
33 | ```php
34 | echo $connection->select()->from(['user' => 'users'])->build();
35 | ```
36 | Output:
37 |
38 | ```sql
39 | SELECT * FROM `users` as `user`;
40 | ```
41 |
42 | ### Retrieving Results
43 |
44 | #### Retrieving All Rows From A Table
45 |
46 | You may use the `select()` method of the `Connection` object to begin a query.
47 | The table method returns a fluent query builder instance for
48 | the given table, allowing you to chain more constraints onto
49 | the query and then finally get the results using the get method:
50 |
51 | ```php
52 | $query = $connection->select()->from('users');
53 | $query->columns(['id', 'username', 'email']);
54 |
55 | $rows = $query->execute()->fetchAll() ?: [];
56 | ```
57 |
58 | The PDO `fetch()` method returns an row containing the results
59 | where each result is an instance of the Array or PHP `stdClass` object.
60 | You may access each column's value by accessing the column as a property of the object:
61 |
62 | ```php
63 | $statement = $connection->select()->from('users')->execute();
64 |
65 | while($row = $statement->fetch(PDO::FETCH_OBJ)) {
66 | echo $row->id;
67 | }
68 | ```
69 |
70 | #### Retrieving A Single Row From A Table
71 |
72 | ```php
73 | $row = $connection->select()->from('users')->execute()->fetch();
74 | ```
75 |
76 | #### Retrieving A Single Column From A Table
77 |
78 | ```php
79 | $value = $connection->select()->from('users')->execute()->fetchColumn(0);
80 | ```
81 |
82 | #### Distinct
83 |
84 | The distinct method allows you to force the query to return distinct results:
85 |
86 | ```php
87 | $query = $connection->select()->from('users')->distinct();
88 |
89 | $query->columns(['id']);
90 |
91 | $rows = $query->execute()->fetchAll();
92 | ```
93 |
94 | #### Columns
95 |
96 | Select columns by name:
97 |
98 | ```php
99 | $query = $connection->select()->from('users');
100 |
101 | $query->columns(['id', 'username', ['first_name' => 'firstName']]);
102 |
103 | $rows = $query->execute()->fetchAll();
104 | ```
105 |
106 | ```sql
107 | SELECT `id`,`username`,`first_name` AS `firstName` FROM `users`;
108 | ```
109 |
110 | Select columns with an array:
111 |
112 | ```php
113 | $query = $connection->select()->from('test');
114 |
115 | $query->columns(['id', 'first_name', 'tablename.fieldname']);
116 |
117 | $rows = $query->execute()->fetchAll();
118 | ```
119 |
120 | Select columns with alias:
121 |
122 | ```php
123 | $query = $connection->select()->from('test');
124 |
125 | $query->columns([
126 | 'firstName' => 'first_name',
127 | 'lastName' => 'last_name',
128 | 'fieldName' => 'tablename.fieldname'
129 | ]);
130 |
131 | $rows = $query->execute()->fetchAll();
132 | ```
133 |
134 | Select columns with alias as array:
135 |
136 | ```php
137 | $query = $this->select()->from('test');
138 |
139 | $query->columns([
140 | 'id',
141 | 'username',
142 | 'firstName' => 'first_name',
143 | 'last_name' => 'test.last_name',
144 | 'email' => 'database.test.email',
145 | 'value' => $query->raw('CONCAT("1","2")')
146 | ]);
147 | ```
148 |
149 | ```sql
150 | SELECT
151 | `id`,
152 | `username`,
153 | `first_name` AS `firstName`,
154 | `test`.`last_name` AS `last_name`,
155 | `database`.`test`.`email` AS `email`,
156 | CONCAT("1","2") AS `value`
157 | FROM
158 | `test`;
159 | ```
160 | Add fields one after another:
161 |
162 | ```php
163 | $query = $connection->select()
164 | ->columns(['first_name'])
165 | ->from('users');
166 |
167 | $rows = $query->columns(['last_name', 'email'])
168 | ->execute()
169 | ->fetchAll();
170 | ```
171 |
172 | ```sql
173 | SELECT `first_name`,`last_name`,`email` FROM `users`;
174 | ```
175 |
176 | #### Sub Selects
177 |
178 | If you want to SELECT FROM a subselect, do so by passing a callback
179 | function and define an alias for the subselect:
180 |
181 | ```php
182 | $query = $connection->select()->from('test');
183 |
184 | $query->columns([
185 | 'id',
186 | function (SelectQuery $subSelect) {
187 | $subSelect->columns($subSelect->raw('MAX(payments.amount)'))
188 | ->from('payments')
189 | ->alias('max_amount');
190 | }
191 | ]);
192 |
193 | $rows = $query->execute()->fetchAll() ?: [];
194 | ```
195 |
196 | ```sql
197 | SELECT `id`,(SELECT MAX(payments.amount) FROM `payments`) AS `max_amount` FROM `test`;
198 | ```
199 |
200 | ### Joins
201 |
202 | #### Inner Join Clause
203 |
204 | The query builder may also be used to write join statements.
205 | To perform a basic "inner join", you may use the join method
206 | on a query builder instance. The first argument passed to
207 | the join method is the name of the table you need to join to,
208 | while the remaining arguments specify the column constraints
209 | for the join. Of course, as you can see, you can join to
210 | multiple tables in a single query:
211 |
212 | ```php
213 | $query = $connection->select()->from('users');
214 |
215 | $query->columns(['users.*', 'contacts.phone', 'orders.price']);
216 |
217 | $query->join('contacts', 'users.id', '=', 'contacts.user_id');
218 | $query->join('orders', 'users.id', '=', 'orders.user_id');
219 |
220 | $rows = $query->execute()->fetchAll() ?: [];
221 | ```
222 |
223 | ```sql
224 | SELECT `users`.*, `contacts`.`phone`, `orders`.`price`
225 | FROM `users`
226 | INNER JOIN `contacts` ON `users`.`id` = `contacts`.`user_id`
227 | INNER JOIN `orders` ON `users`.`id` = `orders`.`user_id`;
228 | ```
229 |
230 | #### Left Join Clause
231 |
232 | If you would like to perform a "left join" instead of an "inner join",
233 | use the leftJoin method. The leftJoin method has the same signature as the join method:
234 |
235 | ```php
236 | $query = $connection->select()->from('users');
237 |
238 | $query->leftJoin('posts', 'users.id', '=', 'posts.user_id');
239 |
240 | $rows = $query->execute()->fetchAll() ?: [];
241 | ```
242 |
243 | ```sql
244 | SELECT *
245 | FROM `users`
246 | LEFT JOIN `posts` ON `users`.`id` = `posts`.`user_id`;
247 | ```
248 |
249 | #### Cross Join Clause
250 |
251 | From the [MySQL JOIN](https://dev.mysql.com/doc/refman/5.7/en/nested-join-optimization.html) docs:
252 |
253 | > In MySQL, CROSS JOIN is syntactically equivalent to INNER JOIN; they can replace each other.
254 | > In standard SQL, they are not equivalent. INNER JOIN is used with an ON clause; CROSS JOIN is used otherwise.
255 |
256 | In MySQL Inner Join and Cross Join yielding the same result.
257 |
258 | Please use the [join](#inner-join-clause) method.
259 |
260 | #### Advanced Join Clauses
261 |
262 | You may also specify more advanced join clauses.
263 | To get started, pass a (raw) string as the second argument into
264 | the `joinRaw` and `leftJoinRaw` method.
265 |
266 | ```php
267 | $query = $connection->select()->from(['u' => 'users']);
268 |
269 | $query->joinRaw(['p' => 'posts'], 'p.user_id=u.id AND u.enabled=1 OR p.published IS NULL');
270 |
271 | $rows = $query->execute()->fetchAll() ?: [];
272 | ```
273 |
274 | ```sql
275 | SELECT `id` FROM `users` AS `u`
276 | INNER JOIN `posts` AS `p` ON (p.user_id=u.id AND u.enabled=1 OR p.published IS NULL);
277 | ```
278 |
279 | ### Unions
280 |
281 | The query builder also provides a quick way to "union" two queries together.
282 | For example, you may create an initial query and use the
283 | `union()`, `unionAll()` and `unionDistinct() `method to union it with a second query:
284 |
285 | ```php
286 | $select = $connection->select()
287 | ->from('table1')
288 | ->columns(['id']);
289 |
290 | $select2 = $connection->select()
291 | ->from('table2')
292 | ->columns(['id']);
293 |
294 | $select->union($select2);
295 | ```
296 |
297 | ```sql
298 | SELECT `id` FROM `table1` UNION SELECT `id` FROM `table2`;
299 | ```
300 |
301 | #### Where Clauses
302 |
303 | Simple Where Clauses
304 |
305 | You may use the where method on a query builder instance
306 | to add where clauses to the query. The most basic call
307 | to where requires three arguments. The first argument is
308 | the name of the column. The second argument is an operator,
309 | which can be any of the database's supported operators.
310 |
311 | Finally, the third argument is the value to evaluate against the column.
312 |
313 | For example, here is a query that verifies the value
314 | of the "votes" column is equal to 100:
315 |
316 | ```php
317 | $rows = $connection->select()
318 | ->from('users')
319 | ->where('votes', '=', 100)
320 | ->execute()
321 | ->fetchAll();
322 | ```
323 |
324 | ```sql
325 | SELECT * FROM `users` WHERE `votes` = 100;
326 | ```
327 |
328 | Of course, you may use a variety of other operators when writing a where clause:
329 |
330 | ```php
331 | $rows = $connection->select()
332 | ->from('users')
333 | ->where('votes', '>=', 100)
334 | ->execute()
335 | ->fetchAll();
336 |
337 | $rows = $connection->select()
338 | ->from('users')
339 | ->where('votes', '<>', 100)
340 | ->execute()
341 | ->fetchAll();
342 |
343 | $rows = $connection->select()
344 | ->from('users')
345 | ->where('name', 'like', 'D%')
346 | ->execute()
347 | ->fetchAll();
348 | ```
349 |
350 | You may also pass multiple AND conditions:
351 |
352 | ```php
353 | $rows = $connection->select()
354 | ->from('users')
355 | ->where('status', '=', 1)
356 | ->where('subscribed', '<>', 1)
357 | ->execute()
358 | ->fetchAll();
359 | ```
360 |
361 | ```sql
362 | SELECT * FROM `users` WHERE `status` = '1' AND `subscribed` <> '1';
363 | ```
364 |
365 | #### Or Statements
366 |
367 | ou may chain where constraints together as well as add OR clauses to the query.
368 | The orWhere method accepts the same arguments as the where method:
369 |
370 | ```php
371 | $rows = $connection->select()
372 | ->from('users')
373 | ->where('votes', '>', 100)
374 | ->orWhere('name', '=', 'John')
375 | ->execute()
376 | ->fetchAll();
377 | ```
378 |
379 | ```sql
380 | SELECT * FROM `users` WHERE `votes` > '100' OR `name` = 'John';
381 | ```
382 |
383 | #### Additional Where Clauses
384 |
385 | ##### Between and not between
386 |
387 | ```php
388 | $rows = $connection->select()
389 | ->from('users')
390 | ->where('votes', 'between', [1, 100])
391 | ->execute()
392 | ->fetchAll();
393 | ```
394 |
395 | ```sql
396 | SELECT * FROM `users` WHERE `votes` BETWEEN '1' AND '100';
397 | ```
398 |
399 |
400 | ```php
401 | $rows = $connection->select()
402 | ->from('users')
403 | ->where('votes', 'not between', [1, 100])
404 | ->execute()
405 | ->fetchAll();
406 | ```
407 |
408 | ```sql
409 | SELECT * FROM `users` WHERE `votes` NOT BETWEEN '1' AND '100';
410 | ```
411 |
412 | ##### In and not in
413 |
414 | ```php
415 | $rows = $connection->select()
416 | ->from('users')
417 | ->where('id', 'in', [1, 2, 3])
418 | ->execute()
419 | ->fetchAll();
420 | ```
421 |
422 | ```sql
423 | SELECT * FROM `users` WHERE `id` IN ('1', '2', '3');
424 | ```
425 |
426 | ```php
427 | $rows = $connection->select()
428 | ->from('users')
429 | ->where('votes', 'not in', [1, 2, 3])
430 | ->execute()
431 | ->fetchAll();
432 | ```
433 |
434 | ```sql
435 | SELECT * FROM `users` WHERE `id` NOT IN ('1', '2', '3');
436 | ```
437 |
438 | ##### Is null and is not null
439 |
440 | ```php
441 | $rows = $connection->select()
442 | ->from('users')
443 | ->where('updated_at', 'is', null)
444 | ->execute()
445 | ->fetchAll();
446 | ```
447 |
448 | ```sql
449 | SELECT * FROM `users` WHERE `updated_at` IS NULL;
450 | ```
451 |
452 | ```php
453 | $rows = $connection->select()
454 | ->from('users')
455 | ->where('updated_at', 'is not', null)
456 | ->execute()
457 | ->fetchAll();
458 | ```
459 |
460 | ```sql
461 | SELECT * FROM `users` WHERE `updated_at` IS NOT NULL;
462 | ```
463 |
464 | If you use the '=' or '<>' for comparison and pass a null value you get the same result.
465 |
466 | ```php
467 | $rows = $connection->select()
468 | ->from('users')
469 | ->where('updated_at', '=', null) // IS NULL
470 | ->execute()
471 | ->fetchAll();
472 | ```
473 |
474 | ```sql
475 | SELECT * FROM `users` WHERE `updated_at` IS NULL;
476 | ```
477 |
478 |
479 | #### Where Column
480 |
481 | The whereColumn method may be used to verify that two columns are equal:
482 |
483 | ```php
484 | $rows = $connection->select()
485 | ->from('users')
486 | ->whereColumn('users.id', '=', 'posts.user_id')
487 | ->execute()
488 | ->fetchAll();
489 | ```
490 |
491 | ```sql
492 | SELECT * FROM `users` WHERE `users`.`id` = `posts`.`user_id`;
493 | ```
494 |
495 | The whereColumn method can also be called multiple times to add multiple conditions.
496 | These conditions will be joined using the and operator:
497 |
498 | ```php
499 | $rows = $connection->select()
500 | ->from('users')
501 | ->whereColumn('first_name', '=', 'last_name')
502 | ->whereColumn('updated_at', '=', 'created_at')
503 | ->execute()
504 | ->fetchAll();
505 | ```
506 |
507 | ```sql
508 | SELECT *
509 | FROM `users`
510 | WHERE `first_name` = `last_name`
511 | AND `updated_at` = `created_at`;
512 | ```
513 |
514 | #### Complex Where Conditions
515 |
516 | ```php
517 | $rows = $connection->select()
518 | ->columns('id', 'username')
519 | ->from('users u')
520 | ->join('customers c', 'c.created_by', '=', 'u.id')
521 | ->leftJoin('articles a', 'a.created_by', '=', 'u.id')
522 | ->where('u.id', '>=', 1)
523 | ->where('u.deleted', '=', 0)
524 | ->orWhere('u.username', 'like', "%a'a%")
525 | ->orWhere('u.username', 'not like', "%a'b%")
526 | ->orWhere('u.id', 'in', [1, 2, 3])
527 | ->orWhere('u.id', 'not in', [4, 5, null])
528 | ->orWhere('u.id', '=', null)
529 | ->orWhere('u.id', '!=', null)
530 | ->where(function (SelectQuery $query) {
531 | $query->where('t2.field', '=', '1');
532 | $query->where('t2.field2', '>', '1');
533 | })
534 | ->orWhere(function (SelectQuery $query) {
535 | $query->where('t.a', '<>', '2');
536 | $query->where('t.b', '=', null);
537 | $query->where('t.c', '>', '5');
538 | $query->orWhere(function (SelectQuery $query) {
539 | $query->where($query->raw('a.id = b.id'));
540 | $query->orWhere($query->raw('c.id = u.id'));
541 | });
542 | })
543 | ->execute()
544 | ->fetchAll();
545 | ```
546 |
547 | #### Where Raw
548 |
549 | Using whereRaw:
550 |
551 | ```php
552 | $query = $connection->select()
553 | ->columns('id', 'username')
554 | ->from('users')
555 | ->whereRaw('status <> 1');
556 |
557 | $rows = $query->execute()->fetchAll();
558 | ```
559 |
560 | ```sql
561 | SELECT `id`, `username` FROM `users` WHERE status <> 1;
562 | ```
563 |
564 | Using a raw expression:
565 |
566 | ```php
567 | $query = $connection->select();
568 | $rows = $query->from('users')
569 | ->where($query->raw('users.id = posts.user_id'))
570 | ->execute()
571 | ->fetchAll();
572 | ```
573 |
574 | ```sql
575 | SELECT * FROM `users` WHERE users.id = posts.user_id;
576 | ```
577 |
578 | #### Order By
579 |
580 | ```php
581 | $rows = $connection->select()
582 | ->from('users')
583 | ->orderBy('updated_at ASC')
584 | ->execute()
585 | ->fetchAll();
586 | ```
587 |
588 | ```sql
589 | SELECT * FROM `users` ORDER BY `updated_at` ASC;
590 | ```
591 |
592 | #### Group By
593 |
594 | ```php
595 | $rows = $connection->select()
596 | ->from('users')
597 | ->groupBy('role')
598 | ->execute()
599 | ->fetchAll();
600 | ```
601 |
602 | ```sql
603 | SELECT * FROM `users` GROUP BY `role`;
604 | ```
605 |
606 | #### Limit and Offset
607 |
608 | ```php
609 | $rows = $connection->select()
610 | ->from('users')
611 | ->limit(10)
612 | ->execute()
613 | ->fetchAll();
614 | ```
615 |
616 | ```sql
617 | SELECT * FROM `users` LIMIT 10;
618 | ```
619 |
620 |
621 |
622 | ```php
623 | $rows = $connection->select()
624 | ->from('users')
625 | ->limit(10)
626 | ->offset(25)
627 | ->execute()
628 | ->fetchAll();
629 | ```
630 |
631 | ```sql
632 | SELECT * FROM `users` LIMIT 25, 10;
633 | ```
634 |
635 | #### Having
636 |
637 | ```php
638 | $rows = $connection->select()
639 | ->from('users')
640 | ->groupBy('id', 'username ASC')
641 | ->having('username', '=', 'admin')
642 | ->execute()
643 | ->fetchAll();
644 | ```
645 |
646 | ```sql
647 | SELECT *
648 | FROM `users`
649 | GROUP BY `id`, `username` ASC
650 | HAVING `username` = 'admin';
651 | ```
652 |
653 | Complex having conditions:
654 |
655 | ```php
656 | $rows = $connection->select()
657 | ->from('users')
658 | ->groupBy(['id', 'username ASC'])
659 | ->having('u.username', '=', 'admin')
660 | ->having('u.username', '=', 'max')
661 | ->having(function(SelectQuery $query) {
662 | $query->having('x', '<>', '2');
663 | $query->having('y', '=', null);
664 | $query->having('z', '<>', '5');
665 | $query->orHaving(function(SelectQuery $query2) {
666 | $query2->having($query2->raw('a.id = b.id'));
667 | $query2->orHaving($query2->raw('c.id = u.id'));
668 | });
669 | })
670 | ->execute()
671 | ->fetchAll();
672 | ```
673 |
674 | ### Using SQL Functions
675 |
676 | A number of commonly used functions can be created with the `func()` method.
677 |
678 | You may call any of these methods after constructing your query:
679 |
680 | * sum() Calculate a sum. The arguments will be treated as literal values.
681 | * avg() Calculate an average. The arguments will be treated as literal values.
682 | * min() Calculate the min of a column. The arguments will be treated as literal values.
683 | * max() Calculate the max of a column. The arguments will be treated as literal values.
684 | * count() Calculate the count. The arguments will be treated as literal values.
685 | * now() Returns a Expression representing a call that will return the current date and time (ISO).
686 |
687 | Example:
688 |
689 | ```php
690 | $query = $connection->select()->from('payments');
691 | $query->columns([$query->func()->sum('amount')->alias('sum_amount')]);
692 |
693 | $rows = $query->execute()->fetchAll() ?: [];
694 | ```
695 |
696 | ```sql
697 | SELECT SUM(`amount`) AS `sum_amount` FROM `payments`;
698 | ```
699 |
700 | #### Using custom SQL Functions
701 |
702 | *This new feature is under construction*
703 |
704 | Whenever you're missing support for some vendor specific function,
705 | please use plain SQL templating:
706 |
707 | {% raw %}
708 | ```php
709 | $query->func()->custom('substring_index(%s, %s, %s)', $string, $delimiter, $number);
710 | ```
711 | {% endraw %}
712 |
713 | ### Raw Expressions
714 |
715 | Sometimes you may need to use a raw expression in a query.
716 |
717 | > These expressions will be injected into the query as strings,
718 | so be careful not to create any SQL injection!
719 |
720 | To create a raw expression, you can use the `raw` method:
721 |
722 | ```php
723 | $query = $connection->select()->from('payments');
724 |
725 | $query->columns([$query->raw('count(*) AS user_count'), 'status']);
726 |
727 | $query->where('status', '<>', 1);
728 | $query->groupBy('status');
729 |
730 | $rows = $query->execute()->fetchAll() ?: [];
731 | ```
732 | Output:
733 | ```sql
734 | SELECT count(*) AS user_count, `status` FROM `payments` WHERE `status` <> 1 GROUP BY `status`;
735 | ```
736 |
737 | Example 2:
738 |
739 | ```php
740 | $query = $connection->select()->from('payments');
741 | $query->columns([$query->raw('count(*) AS user_count'), 'status']);
742 |
743 | $rows = $query->execute()->fetchAll() ?: [];
744 | ```
745 |
746 | Output:
747 |
748 | ```sql
749 | SELECT count(*) AS user_count,`status` FROM `payments`;
750 | ```
751 |
752 | Example 3:
753 |
754 | ```php
755 | $query = $connection->select()->from('payments');
756 |
757 | $query = $query->columns([$query->raw('MAX(amount)'), $query->raw('MIN(amount)')]);
758 |
759 | $rows = $query->execute()->fetchAll() ?: [];
760 | ```
761 |
762 | Output:
763 |
764 | ```sql
765 | SELECT MAX(amount), MIN(amount) FROM `payments`;
766 | ```
767 |
768 | **Next page:** [Inserts](inserts.md)
769 |
--------------------------------------------------------------------------------
/docs/slim.md:
--------------------------------------------------------------------------------
1 | ---
2 | layout: default
3 | title: Slim 4 integration
4 | nav_order: 8
5 | ---
6 |
7 | # Slim 4 integration
8 |
9 | ## Requirements
10 |
11 | * PHP 8+
12 | * MySQL 5.7+
13 | * [A Slim 4 application](https://odan.github.io/2019/11/05/slim4-tutorial.html)
14 | * A DI container (PSR-11), e.g. PHP-DI
15 |
16 | ## Installation
17 |
18 | To add the query builder to your application, run:
19 |
20 | ```
21 | composer require selective/database
22 | ```
23 |
24 | ## Configuration
25 |
26 | Add the database settings to Slim’s settings array, e.g `config/settings.php`:
27 |
28 | ```php
29 | // Database settings
30 | $settings['db'] = [
31 | 'driver' => 'mysql',
32 | 'host' => 'localhost',
33 | 'database' => 'test',
34 | 'username' => 'root',
35 | 'password' => '',
36 | 'charset' => 'utf8mb4',
37 | 'collation' => 'utf8mb4_unicode_ci',
38 | 'prefix' => '',
39 | 'options' => [
40 | // Turn off persistent connections
41 | PDO::ATTR_PERSISTENT => false,
42 | // Enable exceptions
43 | PDO::ATTR_ERRMODE => PDO::ERRMODE_EXCEPTION,
44 | // Emulate prepared statements
45 | PDO::ATTR_EMULATE_PREPARES => true,
46 | // Set default fetch mode to array
47 | PDO::ATTR_DEFAULT_FETCH_MODE => PDO::FETCH_ASSOC,
48 | // Set character set
49 | PDO::MYSQL_ATTR_INIT_COMMAND => 'SET NAMES utf8mb4 COLLATE utf8mb4_unicode_ci'
50 | ],
51 | ];
52 | ```
53 |
54 | Add the following container definitions into your `config/container.php` file:
55 |
56 | ```php
57 | function (ContainerInterface $container) {
72 | return new Connection($container->get(PDO::class));
73 | },
74 |
75 | PDO::class => function (ContainerInterface $container) {
76 | $settings = $container->get('settings')['db'];
77 |
78 | $driver = $settings['driver'];
79 | $host = $settings['host'];
80 | $dbname = $settings['database'];
81 | $username = $settings['username'];
82 | $password = $settings['password'];
83 | $charset = $settings['charset'];
84 | $flags = $settings['flags'];
85 | $dsn = "$driver:host=$host;dbname=$dbname;charset=$charset";
86 |
87 | return new PDO($dsn, $username, $password, $flags);
88 | },
89 | ];
90 | ```
91 |
92 | ### Usage
93 |
94 | You can inject the `Connection` instance into your repository like this:
95 |
96 | ```php
97 | connection = $connection;
111 | }
112 |
113 | public function getUserById(int $userId): array
114 | {
115 | $query = $this->connection->select()->from('users');
116 |
117 | $query->columns(['id', 'username', 'email']);
118 | $query->where('id', '=', $userId);
119 |
120 | $row = $query->execute()->fetch() ?: [];
121 |
122 | if(!$row) {
123 | throw new DomainException(sprintf('User not found: %s', $userId));
124 | }
125 |
126 | return $row;
127 | }
128 |
129 | }
130 | ```
131 |
132 |
133 | **Next page:** [Select](selects.md)
134 |
--------------------------------------------------------------------------------
/docs/updates.md:
--------------------------------------------------------------------------------
1 | ---
2 | layout: default
3 | title: Updates
4 | nav_order: 5
5 | ---
6 |
7 | ## Updates
8 |
9 | Create a update object:
10 |
11 | ```php
12 | use Selective\Database\Connection;
13 |
14 | $connection = new Connection($dsn, $username, $password, $options);
15 | $query = $connection->update();
16 | ```
17 |
18 | Of course, in addition to inserting records into the database,
19 | the query builder can also update existing records using the update method.
20 |
21 | The update method, like the insert method, accepts an array of column
22 | and value pairs containing the columns to be updated.
23 |
24 | You may constrain the update query using where clauses:
25 |
26 | ```php
27 | $status = $connection->update()
28 | ->table('users')
29 | ->set(['votes' => '1'])
30 | ->where('id', '=', '1')
31 | ->execute();
32 | ```
33 |
34 | ```php
35 | $connection->update()
36 | ->table('users')
37 | ->set(['votes' => '1'])
38 | ->where('id', '=', '1')
39 | ->orWhere('id', '=', '2')
40 | ->execute();
41 | ```
42 |
43 | ### Get number of affected rows:
44 |
45 | ```php
46 | $statement = $connection->update()
47 | ->table('users')
48 | ->set(['votes' => '1'])
49 | ->where('id', '=', '1')
50 | ->prepare();
51 |
52 | $statement->execute();
53 | $affectedRowCount = $statement->rowCount();
54 | ```
55 |
56 | ### Increment & Decrement
57 |
58 | The query builder also provides convenient methods for incrementing or
59 | decrementing the value of a given column. This is simply a shortcut,
60 | providing a more expressive and terse interface compared to manually
61 | writing the update statement.
62 |
63 | Both of these methods accept at least one argument: the column to modify.
64 | A second argument may optionally be passed to control the amount by
65 | which the column should be incremented or decremented:
66 |
67 | ```php
68 | $connection->update()
69 | ->table('users')
70 | ->increment('voted')
71 | ->execute();
72 |
73 | $connection->update()
74 | ->table('users')
75 | ->increment('voted', 10)
76 | ->execute();
77 |
78 | $connection->update()
79 | ->table('users')
80 | ->increment('voted', 1)
81 | ->where('id', '=', 1)
82 | ->execute();
83 | ```
84 |
85 | ```php
86 | $connection->update()
87 | ->table('users')
88 | ->decrement('voted', 1)
89 | ->where('id', '=', 1)
90 | ->execute();
91 | ```
92 |
93 | Incrementing without the convenient methods:
94 |
95 | ```php
96 | $query = $connection->update();
97 | $query->table('users')
98 | ->set(['votes' => $query->raw('votes+1')])
99 | ->where('id', '=', '1')
100 | ->execute();
101 | ```
102 |
103 | ### Update Limit
104 |
105 | The `limit` clause places a limit on the number of rows that can be updated.
106 |
107 | ```php
108 | $connection->update()
109 | ->table('users')
110 | ->set(['votes' => '1'])
111 | ->limit(10)
112 | ->execute();
113 | ```
114 |
115 | ### Update Low Priority
116 |
117 | With the `LOW_PRIORITY ` modifier, execution of the UPDATE is delayed until no
118 | other clients are reading from the table. This affects only storage engines
119 | that use only table-level locking (such as MyISAM, MEMORY, and MERGE).
120 |
121 | ```php
122 | $connection->update()
123 | ->table('users')
124 | ->set(['votes' => '1'])
125 | ->lowPriority()
126 | ->execute();
127 | ```
128 |
129 | ### Update and ignore errors
130 |
131 | With the `IGNORE` modifier, the update statement does not abort
132 | even if errors occur during the update. Rows for which duplicate-key
133 | conflicts occur on a unique key value are not updated.
134 |
135 | ```php
136 | $connection->update()
137 | ->table('users')
138 | ->set(['votes' => '1'])
139 | ->ignore()
140 | ->execute();
141 | ```
142 |
143 | ### Update with order by
144 |
145 | If an UPDATE statement includes an ORDER BY clause,
146 | the rows are updated in the order specified by the clause.
147 |
148 | ```php
149 | $connection->update()
150 | ->table('users')
151 | ->set(['votes' => '1'])
152 | ->orderBy('created_at DESC', 'id DESC')
153 | ->execute();
154 | ```
155 |
156 | **Next page:** [Deletes](deletes.md)
157 |
--------------------------------------------------------------------------------
/phpcs.xml:
--------------------------------------------------------------------------------
1 |
2 |
3 |
4 |
5 |
6 |
7 |
8 |
9 | ./src
10 | ./tests
11 |
12 |
13 |
14 |
15 |
16 |
17 |
18 |
19 |
20 |
21 |
22 |
23 |
24 |
25 | warning
26 | */tests/
27 |
28 |
29 | warning
30 |
31 |
32 | warning
33 | */config/
34 |
35 |
36 | warning
37 |
38 |
39 | warning
40 |
41 |
42 | warning
43 |
44 |
45 |
46 |
47 |
48 |
49 |
50 |
51 |
52 |
53 |
54 |
55 |
56 |
57 |
--------------------------------------------------------------------------------
/phpstan.neon:
--------------------------------------------------------------------------------
1 | parameters:
2 | level: max
3 | checkGenericClassInNonGenericObjectType: false
4 | checkMissingIterableValueType: false
5 | treatPhpDocTypesAsCertain: false
6 | paths:
7 | - src
8 | - tests
9 |
--------------------------------------------------------------------------------
/phpunit.xml:
--------------------------------------------------------------------------------
1 |
2 |
8 |
9 |
10 | src
11 |
12 |
13 | vendor
14 | build
15 |
16 |
17 |
18 |
19 | tests
20 |
21 |
22 |
23 |
--------------------------------------------------------------------------------
/src/Condition.php:
--------------------------------------------------------------------------------
1 | quoter = $connection->getQuoter();
47 | $this->query = $query;
48 | }
49 |
50 | /**
51 | * Get sql.
52 | *
53 | * @param array $sql The sql
54 | *
55 | * @return array The sql
56 | */
57 | public function getWhereSql(array $sql): array
58 | {
59 | return $this->getConditionSql($sql, $this->where, 'WHERE');
60 | }
61 |
62 | /**
63 | * Get sql.
64 | *
65 | * @param array $sql The sql
66 | * @param array $where The where
67 | * @param string $conditionType The condition type
68 | *
69 | * @return array The sql
70 | */
71 | public function getConditionSql(array $sql, array $where, string $conditionType): array
72 | {
73 | if (empty($where)) {
74 | return $sql;
75 | }
76 | foreach ($where as $index => $item) {
77 | if ($item instanceof RawExp) {
78 | if ($index === 0) {
79 | $sql[] = $conditionType . ' ' . $item->getValue();
80 | continue;
81 | }
82 | $sql[] = $item->getValue();
83 | continue;
84 | }
85 | [$type, $conditions] = $item;
86 | if (!$index) {
87 | $whereType = $conditionType;
88 | } else {
89 | $whereType = strtoupper($type);
90 | }
91 | if ($conditions[0] instanceof RawExp) {
92 | $sql[] = $whereType . ' ' . $conditions[0]->getValue();
93 | continue;
94 | }
95 | [$leftField, $operator, $rightField] = $conditions;
96 | $leftField = $this->quoter->quoteName($leftField);
97 | [$rightField, $operator] = $this->getRightFieldValue($rightField, $operator);
98 |
99 | $sql[] = sprintf('%s %s %s %s', $whereType, $leftField, $operator, $rightField);
100 | }
101 |
102 | return $sql;
103 | }
104 |
105 | /**
106 | * Comparison Functions and Operators.
107 | *
108 | * https://dev.mysql.com/doc/refman/5.7/en/comparison-operators.html
109 | *
110 | * @param string|array $rightField The right field
111 | * @param string|mixed $comparison The comparison
112 | *
113 | * @return array The value
114 | */
115 | private function getRightFieldValue($rightField, $comparison): array
116 | {
117 | if ($comparison === 'in' || $comparison === 'not in') {
118 | $rightField = '(' . implode(', ', $this->quoter->quoteArray((array)$rightField)) . ')';
119 | } elseif (
120 | $comparison === 'greatest' ||
121 | $comparison === 'least' ||
122 | $comparison === 'coalesce' ||
123 | $comparison === 'interval' ||
124 | $comparison === 'strcmp'
125 | ) {
126 | $comparison = '= ' . $comparison;
127 | $rightField = '(' . implode(', ', $this->quoter->quoteArray((array)$rightField)) . ')';
128 | } elseif ($comparison === '=' && $rightField === null) {
129 | $comparison = 'IS';
130 | $rightField = $this->quoter->quoteValue($rightField);
131 | } elseif (($comparison === '<>' || $comparison === '!=') && $rightField === null) {
132 | $comparison = 'IS NOT';
133 | $rightField = $this->quoter->quoteValue($rightField);
134 | } elseif ($comparison === 'between' || $comparison === 'not between') {
135 | /** @var array $rightField */
136 | $between1 = $this->quoter->quoteValue($rightField[0]);
137 | $between2 = $this->quoter->quoteValue($rightField[1]);
138 | $rightField = sprintf('%s AND %s', $between1, $between2);
139 | } elseif ($rightField instanceof RawExp) {
140 | $rightField = $rightField->getValue();
141 | } else {
142 | $rightField = $this->quoter->quoteValue($rightField);
143 | }
144 |
145 | // @phpstan-ignore-next-line
146 | return [$rightField, strtoupper($comparison)];
147 | }
148 |
149 | /**
150 | * Get sql.
151 | *
152 | * @param array $sql The sql
153 | *
154 | * @return array The result
155 | */
156 | public function getHavingSql(array $sql): array
157 | {
158 | return $this->getConditionSql($sql, $this->having, 'HAVING');
159 | }
160 |
161 | /**
162 | * Where AND condition.
163 | *
164 | * @param array $conditions The conditions (field, comparison, value)
165 | * or (field, comparison, new RawExp('table.field'))
166 | * or new RawExp('...')
167 | *
168 | * @return self
169 | */
170 | public function where(array $conditions): self
171 | {
172 | if ($conditions[0] instanceof Closure) {
173 | $this->addClauseCondClosure('where', 'AND', $conditions[0]);
174 |
175 | return $this;
176 | }
177 | $this->where[] = ['and', $conditions];
178 |
179 | return $this;
180 | }
181 |
182 | /**
183 | * Adds to a clause through a closure, enclosing within parentheses.
184 | *
185 | * @param string $clause The clause to work with, typically 'where' or 'having'
186 | * @param string $andor Add the condition using this operator, typically 'AND' or 'OR'
187 | * @param callable $closure The closure that adds to the clause
188 | *
189 | * @return void
190 | */
191 | private function addClauseCondClosure(string $clause, string $andor, callable $closure): void
192 | {
193 | // Retain the prior set of conditions, and temporarily reset the clause
194 | // for the closure to work with (otherwise there will be an extraneous
195 | // opening AND/OR keyword)
196 | /** @var array $set */
197 | $set = $this->$clause;
198 | $this->$clause = [];
199 | // invoke the closure, which will re-populate the $this->$clause
200 | $closure($this->query);
201 | // are there new clause elements?
202 | if (empty($this->$clause)) {
203 | // no: restore the old ones, and done
204 | $this->$clause = $set;
205 |
206 | return;
207 | }
208 |
209 | // Append an opening parenthesis to the prior set of conditions,
210 | // with AND/OR as needed ...
211 | if (!empty($set)) {
212 | $set[] = new RawExp(strtoupper($andor) . ' (');
213 | } else {
214 | $set[] = new RawExp('(');
215 | }
216 |
217 | // Append the new conditions to the set, with indenting
218 | $sql = [];
219 | $sql = $this->getConditionSql($sql, $this->$clause, '');
220 | foreach ($sql as $cond) {
221 | $set[] = new RawExp($cond);
222 | }
223 | $set[] = new RawExp(')');
224 |
225 | // ... then put the full set of conditions back into $this->$clause
226 | $this->$clause = $set;
227 | }
228 |
229 | /**
230 | * Where OR condition.
231 | *
232 | * @param array $conditions The conditions (field, comparison, value)
233 | * or (field, comparison, new RawExp('table.field'))
234 | * or new RawExp('...')
235 | *
236 | * @return self
237 | */
238 | public function orWhere(array $conditions): self
239 | {
240 | if ($conditions[0] instanceof Closure) {
241 | $this->addClauseCondClosure('where', 'OR', $conditions[0]);
242 |
243 | return $this;
244 | }
245 | $this->where[] = ['or', $conditions];
246 |
247 | return $this;
248 | }
249 |
250 | /**
251 | * Add AND having condition.
252 | *
253 | * @param array $conditions The conditions (field, comparison, value)
254 | * or (field, comparison, new RawExp('table.field'))
255 | * or new RawExp('...')
256 | *
257 | * @return self
258 | */
259 | public function having(array $conditions): self
260 | {
261 | if ($conditions[0] instanceof Closure) {
262 | $this->addClauseCondClosure('having', 'AND', $conditions[0]);
263 |
264 | return $this;
265 | }
266 | $this->having[] = ['and', $conditions];
267 |
268 | return $this;
269 | }
270 |
271 | /**
272 | * Add OR having condition.
273 | *
274 | * @param array $conditions The conditions (field, comparison, value)
275 | * or (field, comparison, new RawExp('table.field'))
276 | * or new RawExp('...')
277 | *
278 | * @return self
279 | */
280 | public function orHaving(array $conditions): self
281 | {
282 | if ($conditions[0] instanceof Closure) {
283 | $this->addClauseCondClosure('having', 'OR', $conditions[0]);
284 |
285 | return $this;
286 | }
287 | $this->having[] = ['or', $conditions];
288 |
289 | return $this;
290 | }
291 | }
292 |
--------------------------------------------------------------------------------
/src/Connection.php:
--------------------------------------------------------------------------------
1 | pdo = $pdo;
30 | $this->quoter = new Quoter($this);
31 | }
32 |
33 | /**
34 | * @return SelectQuery
35 | */
36 | public function select(): SelectQuery
37 | {
38 | return new SelectQuery($this);
39 | }
40 |
41 | /**
42 | * @return InsertQuery
43 | */
44 | public function insert(): InsertQuery
45 | {
46 | return new InsertQuery($this);
47 | }
48 |
49 | /**
50 | * @return UpdateQuery
51 | */
52 | public function update(): UpdateQuery
53 | {
54 | return new UpdateQuery($this);
55 | }
56 |
57 | /**
58 | * @return DeleteQuery
59 | */
60 | public function delete(): DeleteQuery
61 | {
62 | return new DeleteQuery($this);
63 | }
64 |
65 | /**
66 | * Get PDO.
67 | *
68 | * @return PDO
69 | */
70 | public function getPdo(): PDO
71 | {
72 | return $this->pdo;
73 | }
74 |
75 | /**
76 | * Get quoter.
77 | *
78 | * @return Quoter
79 | */
80 | public function getQuoter(): Quoter
81 | {
82 | return $this->quoter;
83 | }
84 | }
85 |
--------------------------------------------------------------------------------
/src/DatabaseException.php:
--------------------------------------------------------------------------------
1 | pdo = $connection->getPdo();
76 | $this->quoter = $connection->getQuoter();
77 | $this->condition = new Condition($connection, $this);
78 | }
79 |
80 | /**
81 | * Priority modifier.
82 | *
83 | * If you specify LOW_PRIORITY, the server delays execution of the
84 | * DELETE until no other clients are reading from the table.
85 | *
86 | * This affects only storage engines that use only table-level
87 | * locking (such as MyISAM, MEMORY, and MERGE).
88 | *
89 | * @return self
90 | */
91 | public function lowPriority(): self
92 | {
93 | $this->priority = 'LOW_PRIORITY';
94 |
95 | return $this;
96 | }
97 |
98 | /**
99 | * Ignore errors modifier.
100 | *
101 | * @return self
102 | */
103 | public function ignore(): self
104 | {
105 | $this->ignore = 'IGNORE';
106 |
107 | return $this;
108 | }
109 |
110 | /**
111 | * Quick modifier.
112 | *
113 | * For MyISAM tables, if you use the QUICK modifier,
114 | * the storage engine does not merge index leaves during delete,
115 | * which may speed up some kinds of delete operations.
116 | *
117 | * @return self
118 | */
119 | public function quick(): self
120 | {
121 | $this->quick = 'QUICK';
122 |
123 | return $this;
124 | }
125 |
126 | /**
127 | * Table name.
128 | *
129 | * @param string $table Table name
130 | *
131 | * @return self
132 | */
133 | public function from(string $table): self
134 | {
135 | $this->table = $table;
136 |
137 | return $this;
138 | }
139 |
140 | /**
141 | * Where AND condition.
142 | *
143 | * @param array ...$conditions The condition (field, comparison, value)
144 | * or (field, comparison, new RawExp('table.field'))
145 | * or new RawExp('...')
146 | *
147 | * @return self
148 | */
149 | public function where(...$conditions): self
150 | {
151 | $this->condition->where($conditions);
152 |
153 | return $this;
154 | }
155 |
156 | /**
157 | * Where OR condition.
158 | *
159 | * @param array ...$conditions The conditions (field, comparison, value)
160 | * or (field, comparison, new RawExp('table.field'))
161 | * or new RawExp('...')
162 | *
163 | * @return self
164 | */
165 | public function orWhere(...$conditions): self
166 | {
167 | $this->condition->orWhere($conditions);
168 |
169 | return $this;
170 | }
171 |
172 | /**
173 | * Order by.
174 | *
175 | * @param array ...$fields Column name(s)
176 | *
177 | * @return self
178 | */
179 | public function orderBy(...$fields): self
180 | {
181 | $this->orderBy = $fields;
182 |
183 | return $this;
184 | }
185 |
186 | /**
187 | * Limit the number of rows returned.
188 | *
189 | * @param int $rowCount Row count
190 | *
191 | * @return self
192 | */
193 | public function limit(int $rowCount): self
194 | {
195 | $this->limit = $rowCount;
196 |
197 | return $this;
198 | }
199 |
200 | /**
201 | * Truncate the entire table.
202 | *
203 | * @return self
204 | */
205 | public function truncate(): self
206 | {
207 | $this->truncate = true;
208 |
209 | return $this;
210 | }
211 |
212 | /**
213 | * Executes a prepared statement.
214 | *
215 | * @return bool
216 | */
217 | public function execute(): bool
218 | {
219 | return $this->prepare()->execute();
220 | }
221 |
222 | /**
223 | * Prepares a statement for execution and returns a statement object.
224 | *
225 | * @throws RuntimeException
226 | *
227 | * @return PDOStatement
228 | */
229 | public function prepare(): PDOStatement
230 | {
231 | $statement = $this->pdo->prepare($this->build());
232 |
233 | if (!$statement instanceof PDOStatement) {
234 | throw new RuntimeException('The database statement could not be prepared.');
235 | }
236 |
237 | return $statement;
238 | }
239 |
240 | /**
241 | * Build a SQL string.
242 | *
243 | * @return string SQL string
244 | */
245 | public function build(): string
246 | {
247 | if ($this->truncate === true) {
248 | return $this->getTruncateSql();
249 | }
250 | $sql = [];
251 | $sql = $this->getDeleteSql($sql);
252 | $sql = $this->condition->getWhereSql($sql);
253 | $sql = $this->getOrderBySql($sql);
254 | $sql = $this->getLimitSql($sql);
255 |
256 | return trim(implode(' ', $sql)) . ';';
257 | }
258 |
259 | /**
260 | * Get sql.
261 | *
262 | * @return string The sql
263 | */
264 | private function getTruncateSql(): string
265 | {
266 | return 'TRUNCATE TABLE ' . $this->quoter->quoteName($this->table) . ';';
267 | }
268 |
269 | /**
270 | * Get sql.
271 | *
272 | * @param array $sql The sql
273 | *
274 | * @return array The sql
275 | */
276 | private function getDeleteSql(array $sql): array
277 | {
278 | $delete = 'DELETE';
279 | if (!empty($this->priority)) {
280 | $delete .= ' ' . $this->priority;
281 | }
282 | if (!empty($this->quick)) {
283 | $delete .= ' ' . $this->quick;
284 | }
285 | if (!empty($this->ignore)) {
286 | $delete .= ' ' . $this->ignore;
287 | }
288 | $sql[] = $delete . ' FROM ' . $this->quoter->quoteName($this->table);
289 |
290 | return $sql;
291 | }
292 |
293 | /**
294 | * Get sql.
295 | *
296 | * @param array $sql The sql
297 | *
298 | * @return array The sql
299 | */
300 | private function getOrderBySql(array $sql): array
301 | {
302 | if (empty($this->orderBy)) {
303 | return $sql;
304 | }
305 | $sql[] = 'ORDER BY ' . implode(', ', $this->quoter->quoteByFields($this->orderBy));
306 |
307 | return $sql;
308 | }
309 |
310 | /**
311 | * Get sql.
312 | *
313 | * @param array $sql The sql
314 | *
315 | * @return array The sql
316 | */
317 | private function getLimitSql(array $sql): array
318 | {
319 | if (!isset($this->limit)) {
320 | return $sql;
321 | }
322 | $sql[] = sprintf('LIMIT %s', $this->limit);
323 |
324 | return $sql;
325 | }
326 | }
327 |
--------------------------------------------------------------------------------
/src/FunctionBuilder.php:
--------------------------------------------------------------------------------
1 | db = $db;
27 | }
28 |
29 | /**
30 | * Calculate a sum. The arguments will be treated as literal values.
31 | *
32 | * @param string $field Field name
33 | *
34 | * @return FunctionExpression Expression
35 | */
36 | public function sum(string $field): FunctionExpression
37 | {
38 | $quoter = $this->db->getQuoter();
39 | $expression = sprintf('SUM(%s)', $quoter->quoteName($field));
40 |
41 | return new FunctionExpression($expression, $quoter);
42 | }
43 |
44 | /**
45 | * Calculate an average. The arguments will be treated as literal values.
46 | *
47 | * @param string $field Field name
48 | *
49 | * @return FunctionExpression Expression
50 | */
51 | public function avg(string $field): FunctionExpression
52 | {
53 | $quoter = $this->db->getQuoter();
54 | $expression = sprintf('AVG(%s)', $quoter->quoteName($field));
55 |
56 | return new FunctionExpression($expression, $quoter);
57 | }
58 |
59 | /**
60 | * Calculate the min of a column. The arguments will be treated as literal values.
61 | *
62 | * @param string $field Field name
63 | *
64 | * @return FunctionExpression Expression
65 | */
66 | public function min(string $field): FunctionExpression
67 | {
68 | $quoter = $this->db->getQuoter();
69 | $expression = sprintf('MIN(%s)', $quoter->quoteName($field));
70 |
71 | return new FunctionExpression($expression, $quoter);
72 | }
73 |
74 | /**
75 | * Calculate the max of a column. The arguments will be treated as literal values.
76 | *
77 | * @param string $field Field name
78 | *
79 | * @return FunctionExpression Expression
80 | */
81 | public function max(string $field): FunctionExpression
82 | {
83 | $quoter = $this->db->getQuoter();
84 | $expression = sprintf('MAX(%s)', $quoter->quoteName($field));
85 |
86 | return new FunctionExpression($expression, $quoter);
87 | }
88 |
89 | /**
90 | * Calculate the count. The arguments will be treated as literal values.
91 | *
92 | * @param string $field Field name (Default is *)
93 | *
94 | * @return FunctionExpression Expression
95 | */
96 | public function count(string $field = '*'): FunctionExpression
97 | {
98 | $quoter = $this->db->getQuoter();
99 | $expression = sprintf('COUNT(%s)', $quoter->quoteName($field));
100 |
101 | return new FunctionExpression($expression, $quoter);
102 | }
103 |
104 | /**
105 | * Returns a Expression representing a call that will return the current date and time (ISO).
106 | *
107 | * @return FunctionExpression Expression
108 | */
109 | public function now(): FunctionExpression
110 | {
111 | return new FunctionExpression('NOW()', $this->db->getQuoter());
112 | }
113 |
114 | /**
115 | * Create custom SQL function call.
116 | *
117 | * @param string $name The name of the function
118 | * @param mixed ...$parameters The parameters for the function
119 | *
120 | * @return FunctionExpression Expression
121 | */
122 | public function call(string $name, ...$parameters): FunctionExpression
123 | {
124 | $quoter = $this->db->getQuoter();
125 |
126 | $list = implode(', ', $quoter->quoteArray($parameters));
127 | $expression = sprintf('%s(%s)', strtoupper($name), $list);
128 |
129 | return new FunctionExpression($expression, $quoter);
130 | }
131 |
132 | /**
133 | * Returns a quoted field.
134 | *
135 | * @param string $field Field name
136 | *
137 | * @return FunctionExpression Expression
138 | */
139 | public function field(string $field): FunctionExpression
140 | {
141 | $quoter = $this->db->getQuoter();
142 | $expression = $quoter->quoteName($field);
143 |
144 | return new FunctionExpression($expression, $quoter);
145 | }
146 | }
147 |
--------------------------------------------------------------------------------
/src/FunctionExpression.php:
--------------------------------------------------------------------------------
1 | quoter = $quoter;
27 | }
28 |
29 | /**
30 | * Alias.
31 | *
32 | * @param string $alias Alias
33 | *
34 | * @return $this The self instance
35 | */
36 | public function alias(string $alias): self
37 | {
38 | $clone = clone $this;
39 | $clone->value = sprintf('%s AS %s', $clone->value, $this->quoter->quoteName($alias));
40 |
41 | return $clone;
42 | }
43 | }
44 |
--------------------------------------------------------------------------------
/src/InsertQuery.php:
--------------------------------------------------------------------------------
1 | pdo = $connection->getPdo();
61 | $this->quoter = $connection->getQuoter();
62 | }
63 |
64 | /**
65 | * Table name.
66 | *
67 | * @param string $table Table name
68 | *
69 | * @return self The self instance
70 | */
71 | public function into(string $table): self
72 | {
73 | $this->table = $table;
74 |
75 | return $this;
76 | }
77 |
78 | /**
79 | * Priority modifier.
80 | *
81 | * @return self The self instance
82 | */
83 | public function lowPriority(): self
84 | {
85 | $this->priority = 'LOW_PRIORITY';
86 |
87 | return $this;
88 | }
89 |
90 | /**
91 | * Priority modifier.
92 | *
93 | * @return self The self instance
94 | */
95 | public function delayed(): self
96 | {
97 | $this->priority = 'DELAYED';
98 |
99 | return $this;
100 | }
101 |
102 | /**
103 | * Priority modifier.
104 | *
105 | * @return self The self instance
106 | */
107 | public function highPriority(): self
108 | {
109 | $this->priority = 'HIGH_PRIORITY';
110 |
111 | return $this;
112 | }
113 |
114 | /**
115 | * Ignore errors modifier.
116 | *
117 | * @return self The self instance
118 | */
119 | public function ignore(): self
120 | {
121 | $this->ignore = 'IGNORE';
122 |
123 | return $this;
124 | }
125 |
126 | /**
127 | * On Duplicate Key Update.
128 | *
129 | * @param array $values Value list
130 | *
131 | * @return self The self instance
132 | */
133 | public function onDuplicateKeyUpdate(array $values): self
134 | {
135 | $this->duplicateValues = $values;
136 |
137 | return $this;
138 | }
139 |
140 | /**
141 | * Execute.
142 | *
143 | * @return bool Success
144 | */
145 | public function execute(): bool
146 | {
147 | return $this->prepare()->execute();
148 | }
149 |
150 | /**
151 | * Prepare statement.
152 | *
153 | * @throws RuntimeException
154 | *
155 | * @return PDOStatement The pdo statement
156 | */
157 | public function prepare(): PDOStatement
158 | {
159 | $statement = $this->pdo->prepare($this->build());
160 |
161 | if (!$statement instanceof PDOStatement) {
162 | throw new RuntimeException('The database statement could not be prepared.');
163 | }
164 |
165 | return $statement;
166 | }
167 |
168 | /**
169 | * Build a SQL string.
170 | *
171 | * @return string The SQL string
172 | */
173 | public function build(): string
174 | {
175 | $table = $this->quoter->quoteName($this->table);
176 |
177 | $insert = 'INSERT';
178 | if (!empty($this->priority)) {
179 | $insert .= ' ' . $this->priority;
180 | }
181 | if (!empty($this->ignore)) {
182 | $insert .= ' ' . $this->ignore;
183 | }
184 |
185 | if (array_key_exists(0, $this->values)) {
186 | // multiple rows
187 | $result = sprintf('%s INTO %s (%s) VALUES', $insert, $table, $this->quoter->quoteFields($this->values[0]));
188 | foreach ($this->values as $key => $row) {
189 | $result .= sprintf('%s(%s)', ($key > 0) ? ',' : '', $this->quoter->quoteBulkValues($row));
190 | }
191 | } else {
192 | // single row
193 | $result = sprintf('%s INTO %s SET %s', $insert, $table, $this->quoter->quoteSetValues($this->values));
194 | }
195 |
196 | if ($this->duplicateValues) {
197 | $values = $this->quoter->quoteSetValues($this->duplicateValues);
198 | $result .= sprintf(' ON DUPLICATE KEY UPDATE %s', $values);
199 | }
200 | $result .= ';';
201 |
202 | return $result;
203 | }
204 |
205 | /**
206 | * Returns the ID of the last inserted row or sequence value.
207 | *
208 | * @param string|null $name The name of the sequence object from which the ID should be returned. Optional.
209 | *
210 | * @return string Last inserted Id
211 | */
212 | public function lastInsertId(string $name = null): string
213 | {
214 | if ($name === null) {
215 | return $this->pdo->lastInsertId() ?: '0';
216 | }
217 |
218 | return $this->pdo->lastInsertId($name) ?: '0';
219 | }
220 |
221 | /**
222 | * Insert new row(s) and return new Id.
223 | *
224 | * @param array $values Values
225 | *
226 | * @return string Last inserted Id
227 | */
228 | public function insertGetId(array $values): string
229 | {
230 | $stmt = $this->set($values)->prepare();
231 | $stmt->execute();
232 |
233 | return $this->lastInsertId();
234 | }
235 |
236 | /**
237 | * Value list.
238 | *
239 | * @param array $values Value list
240 | *
241 | * @return self The self instance
242 | */
243 | public function set(array $values): self
244 | {
245 | $this->values = $values;
246 |
247 | return $this;
248 | }
249 | }
250 |
--------------------------------------------------------------------------------
/src/Operator.php:
--------------------------------------------------------------------------------
1 | ';
14 | public const NOT_EQ_NULL_SAFE = '<=>';
15 | public const LT = '<';
16 | public const GT = '>';
17 | public const GTE = '>=';
18 | public const LTE = '<=';
19 | public const IS = 'is';
20 | public const IS_NOT = 'is not';
21 | public const LIKE = 'like';
22 | public const NOT_LIKE = 'not like';
23 | public const SOUNDS_LIKE = 'sounds like';
24 | public const IN = 'in';
25 | public const NOT_IN = 'not in';
26 | public const EXISTS = 'exists';
27 | public const NOT_EXISTS = 'not exists';
28 | public const BETWEEN = 'between';
29 | public const NOT_BETWEEN = 'not between';
30 | public const REGEXP = 'regexp';
31 | public const NOT_REGEXP = 'not regexp';
32 | public const BINARY = 'binary';
33 | public const CASE = 'case';
34 | public const PLUS = '+';
35 | public const MINUS = '-';
36 | public const MULTIPLY = '*';
37 | public const DIVIDE = '/';
38 | public const DIV = 'div';
39 | public const RIGHT_SHIFT = '>>';
40 | public const LEFT_SHIFT = '<<';
41 | public const MOD = 'mod';
42 | public const AND = 'and';
43 | public const OR = 'or';
44 | public const XOR = 'xor';
45 | }
46 |
--------------------------------------------------------------------------------
/src/QueryInterface.php:
--------------------------------------------------------------------------------
1 | pdo = $connection->getPdo();
29 | }
30 |
31 | /**
32 | * Quote array values.
33 | *
34 | * @param array $array The values
35 | *
36 | * @return array The quoted values
37 | */
38 | public function quoteArray(array $array): array
39 | {
40 | if (empty($array)) {
41 | return [];
42 | }
43 | foreach ($array as $key => $value) {
44 | if ($value instanceof RawExp) {
45 | $array[$key] = $value->getValue();
46 | continue;
47 | }
48 |
49 | $array[$key] = $this->quoteValue($value);
50 | }
51 |
52 | return $array;
53 | }
54 |
55 | /**
56 | * Quotes a value for use in a query.
57 | *
58 | * @param mixed $value The value
59 | *
60 | * @throws RuntimeException
61 | *
62 | * @return string A quoted string
63 | */
64 | public function quoteValue($value): string
65 | {
66 | if ($value === null) {
67 | return 'NULL';
68 | }
69 |
70 | // @phpstan-ignore-next-line
71 | $result = $this->pdo->quote((string)$value);
72 |
73 | if (!is_string($result)) {
74 | throw new UnexpectedValueException('The database driver does not support quoting in this way.');
75 | }
76 |
77 | return $result;
78 | }
79 |
80 | /**
81 | * Quote array of names.
82 | *
83 | * @param array $identifiers The identifiers
84 | *
85 | * @return array The quoted identifiers
86 | */
87 | public function quoteNames(array $identifiers): array
88 | {
89 | foreach ($identifiers as $key => $identifier) {
90 | if ($identifier instanceof RawExp) {
91 | $identifiers[$key] = $identifier->getValue();
92 | continue;
93 | }
94 | $identifiers[$key] = $this->quoteName($identifier);
95 | }
96 |
97 | return $identifiers;
98 | }
99 |
100 | /**
101 | * Escape identifier (column, table) with backticks.
102 | *
103 | * @see: http://dev.mysql.com/doc/refman/8.0/en/identifiers.html
104 | *
105 | * @param string|array $identifier Identifier name
106 | *
107 | * @return string Quoted identifier
108 | */
109 | public function quoteName($identifier): string
110 | {
111 | if (is_array($identifier)) {
112 | $key = (string)array_key_first($identifier);
113 | $value = $identifier[$key];
114 |
115 | if ($value instanceof RawExp) {
116 | return sprintf('%s AS %s', $value->getValue(), $this->quoteIdentifier($key));
117 | }
118 |
119 | return sprintf('%s AS %s', $this->quoteName($identifier[$key]), $this->quoteIdentifier($key));
120 | }
121 |
122 | $identifier = trim($identifier);
123 | $separators = ['.'];
124 | foreach ($separators as $sep) {
125 | $pos = strripos($identifier, $sep);
126 | if ($pos) {
127 | return $this->quoteNameWithSeparator($identifier, $sep, $pos);
128 | }
129 | }
130 |
131 | return $this->quoteIdentifier($identifier);
132 | }
133 |
134 | /**
135 | * Quotes an identifier that has a separator.
136 | *
137 | * @param string $spec The identifier name to quote
138 | * @param string $sep The separator, typically a dot or space
139 | * @param int $pos The position of the separator
140 | *
141 | * @return string The quoted identifier name
142 | */
143 | private function quoteNameWithSeparator(string $spec, string $sep, int $pos): string
144 | {
145 | $len = strlen($sep);
146 | $part1 = $this->quoteName(substr($spec, 0, $pos));
147 | $part2 = $this->quoteIdentifier(substr($spec, $pos + $len));
148 |
149 | return "{$part1}{$sep}{$part2}";
150 | }
151 |
152 | /**
153 | * Quotes an identifier name (table, index, etc); ignores empty values and
154 | * values of '*'.
155 | *
156 | * Escape backticks inside by doubling them
157 | * Enclose identifier in backticks
158 | *
159 | * After such formatting, it is safe to insert the $table variable into query.
160 | *
161 | * @param string $name The identifier name to quote
162 | *
163 | * @return string The quoted identifier name
164 | *
165 | * @see quoteName()
166 | */
167 | public function quoteIdentifier(string $name): string
168 | {
169 | $name = trim($name);
170 | if ($name === '*') {
171 | return $name;
172 | }
173 |
174 | return '`' . str_replace('`', '``', $name) . '`';
175 | }
176 |
177 | /**
178 | * Quote Set values.
179 | *
180 | * @param array $row A row
181 | *
182 | * @return string Sql string
183 | */
184 | public function quoteSetValues(array $row): string
185 | {
186 | $values = [];
187 | foreach ($row as $key => $value) {
188 | if ($value instanceof RawExp) {
189 | $values[] = $this->quoteName($key) . '=' . $value->getValue();
190 | continue;
191 | }
192 | $values[] = $this->quoteName($key) . '=' . $this->quoteValue($value);
193 | }
194 |
195 | return implode(', ', $values);
196 | }
197 |
198 | /**
199 | * Quote bulk values.
200 | *
201 | * @param array $row A row
202 | *
203 | * @return string Sql string
204 | */
205 | public function quoteBulkValues(array $row): string
206 | {
207 | $values = [];
208 | foreach ($row as $key => $value) {
209 | $values[] = $this->quoteValue($value);
210 | }
211 |
212 | return implode(',', $values);
213 | }
214 |
215 | /**
216 | * Quote fields values.
217 | *
218 | * @param array $row A row
219 | *
220 | * @return string Sql string
221 | */
222 | public function quoteFields(array $row): string
223 | {
224 | $fields = [];
225 | foreach (array_keys($row) as $field) {
226 | $fields[] = $this->quoteName($field);
227 | }
228 |
229 | return implode(', ', $fields);
230 | }
231 |
232 | /**
233 | * Get sql.
234 | *
235 | * @param array $identifiers The identifiers
236 | *
237 | * @return array The quoted identifiers
238 | */
239 | public function quoteByFields(array $identifiers): array
240 | {
241 | foreach ($identifiers as $key => $identifier) {
242 | if ($identifier instanceof RawExp) {
243 | $identifiers[$key] = $identifier->getValue();
244 | continue;
245 | }
246 | // table.id ASC
247 | if (preg_match('/^([\w\-\.]+)(\s)*(.*)$/', $identifier, $match)) {
248 | $identifiers[$key] = $this->quoteName($match[1]) . $match[2] . $match[3];
249 | continue;
250 | }
251 | $identifiers[$key] = $this->quoteName($identifier);
252 | }
253 |
254 | return $identifiers;
255 | }
256 | }
257 |
--------------------------------------------------------------------------------
/src/RawExp.php:
--------------------------------------------------------------------------------
1 | value = $value;
23 | }
24 |
25 | /**
26 | * To string.
27 | *
28 | * @return string The string value
29 | */
30 | public function __toString()
31 | {
32 | return $this->getValue();
33 | }
34 |
35 | /**
36 | * Get value.
37 | *
38 | * @return string The string value
39 | */
40 | public function getValue(): string
41 | {
42 | return $this->value;
43 | }
44 | }
45 |
--------------------------------------------------------------------------------
/src/SelectQuery.php:
--------------------------------------------------------------------------------
1 | connection = $connection;
117 | $this->pdo = $connection->getPdo();
118 | $this->quoter = $connection->getQuoter();
119 | $this->condition = new Condition($connection, $this);
120 | }
121 |
122 | /**
123 | * Distinct.
124 | *
125 | * @return self
126 | */
127 | public function distinct(): self
128 | {
129 | $this->distinct = 'DISTINCT';
130 |
131 | return $this;
132 | }
133 |
134 | /**
135 | * Distinct row.
136 | *
137 | * @return self
138 | */
139 | public function distinctRow(): self
140 | {
141 | $this->distinct = 'DISTINCTROW';
142 |
143 | return $this;
144 | }
145 |
146 | /**
147 | * Distinct row.
148 | *
149 | * @return self
150 | */
151 | public function straightJoin(): self
152 | {
153 | $this->straightJoin = 'STRAIGHT_JOIN';
154 |
155 | return $this;
156 | }
157 |
158 | /**
159 | * High Priority.
160 | *
161 | * @return self
162 | */
163 | public function highPriority(): self
164 | {
165 | $this->highPriority = 'HIGH_PRIORITY';
166 |
167 | return $this;
168 | }
169 |
170 | /**
171 | * Small Result.
172 | *
173 | * @return self
174 | */
175 | public function smallResult(): self
176 | {
177 | $this->resultSize = 'SQL_SMALL_RESULT';
178 |
179 | return $this;
180 | }
181 |
182 | /**
183 | * Big Result.
184 | *
185 | * @return self
186 | */
187 | public function bigResult(): self
188 | {
189 | $this->resultSize = 'SQL_BIG_RESULT';
190 |
191 | return $this;
192 | }
193 |
194 | /**
195 | * Buffer Result.
196 | *
197 | * @return self
198 | */
199 | public function bufferResult(): self
200 | {
201 | $this->bufferResult = 'SQL_BUFFER_RESULT';
202 |
203 | return $this;
204 | }
205 |
206 | /**
207 | * Calc Found Rows.
208 | *
209 | * @return self
210 | */
211 | public function calcFoundRows(): self
212 | {
213 | $this->calcFoundRows = 'SQL_CALC_FOUND_ROWS';
214 |
215 | return $this;
216 | }
217 |
218 | /**
219 | * Adds new fields to be returned by a `SELECT` statement when this query is
220 | * executed. Fields can be passed as an array of strings, array of expression
221 | * objects, a single expression or a single string.
222 | *
223 | * If an array is passed, keys will be used to alias fields using the value as the
224 | * real field to be aliased. It is possible to alias strings, Expression objects or
225 | * even other Query objects.
226 | *
227 | * This method will append any passed argument to the list of fields to be selected.
228 | *
229 | * @param array $columns The columns as array
230 | *
231 | * @return self
232 | */
233 | public function columns(array $columns): self
234 | {
235 | if (empty($this->columns)) {
236 | $this->columns = $columns;
237 | } else {
238 | foreach ($columns as $column) {
239 | $this->columns[] = $column;
240 | }
241 | }
242 |
243 | return $this;
244 | }
245 |
246 | /**
247 | * Alias for sub selects.
248 | *
249 | * @param string $alias The alias
250 | *
251 | * @return self
252 | */
253 | public function alias(string $alias): self
254 | {
255 | $this->alias = $alias;
256 |
257 | return $this;
258 | }
259 |
260 | /**
261 | * From.
262 | *
263 | * @param string|array $table Table name
264 | *
265 | * @return self
266 | */
267 | public function from($table): self
268 | {
269 | $this->from = $table;
270 |
271 | return $this;
272 | }
273 |
274 | /**
275 | * UNION is used to combine the result from multiple
276 | * SELECT statements into a single result set.
277 | *
278 | * @param SelectQuery $query The query to combine
279 | *
280 | * @return self
281 | */
282 | public function union(SelectQuery $query): self
283 | {
284 | $this->union[] = ['', $query->build(false)];
285 |
286 | return $this;
287 | }
288 |
289 | /**
290 | * UNION ALL is used to combine the result from multiple
291 | * SELECT statements into a single result set.
292 | *
293 | * @param SelectQuery $query The query to combine
294 | *
295 | * @return self
296 | */
297 | public function unionAll(SelectQuery $query): self
298 | {
299 | $this->union[] = ['ALL', $query->build(false)];
300 |
301 | return $this;
302 | }
303 |
304 | /**
305 | * UNION DISTINCT is used to combine the result from multiple
306 | * SELECT statements into a single result set.
307 | *
308 | * @param SelectQuery $query The query to combine
309 | *
310 | * @return self
311 | */
312 | public function unionDistinct(SelectQuery $query): self
313 | {
314 | $this->union[] = ['DISTINCT', $query->build(false)];
315 |
316 | return $this;
317 | }
318 |
319 | /**
320 | * Join.
321 | *
322 | * @param string|array $table Table name
323 | * @param string $leftField Name of the left field
324 | * @param string $comparison Comparison (=,<,>,<=,>=,<>,in, not in, between, not between)
325 | * @param mixed $rightField Value of the right field
326 | *
327 | * @return self
328 | */
329 | public function join($table, string $leftField, string $comparison, $rightField): self
330 | {
331 | $this->join[] = ['inner', $table, $leftField, $comparison, $rightField];
332 |
333 | return $this;
334 | }
335 |
336 | /**
337 | * Inner Join (alias).
338 | *
339 | * @param string|array $table Table name
340 | * @param string $leftField Name of the left field
341 | * @param string $comparison Comparison (=,<,>,<=,>=,<>,in, not in, between, not between)
342 | * @param mixed $rightField Value of the right field
343 | *
344 | * @return self
345 | */
346 | public function innerJoin($table, string $leftField, string $comparison, $rightField): self
347 | {
348 | return $this->join($table, $leftField, $comparison, $rightField);
349 | }
350 |
351 | /**
352 | * Left Join.
353 | *
354 | * @param string|array $table Table name
355 | * @param string $leftField Name of the left field
356 | * @param string $comparison Comparison (=,<,>,<=,>=,<>,in, not in, between, not between)
357 | * @param mixed $rightField Value of the right field
358 | *
359 | * @return self
360 | */
361 | public function leftJoin($table, string $leftField, string $comparison, $rightField): self
362 | {
363 | $this->join[] = ['left', $table, $leftField, $comparison, $rightField];
364 |
365 | return $this;
366 | }
367 |
368 | /**
369 | * Join with complex conditions.
370 | *
371 | * @param string|array $table Table name
372 | * @param string $conditions The ON conditions e.g. 'user.id = article.user_id'
373 | *
374 | * @return self
375 | */
376 | public function joinRaw($table, string $conditions): self
377 | {
378 | $this->join[] = ['inner', $table, new RawExp($conditions), null, null, null];
379 |
380 | return $this;
381 | }
382 |
383 | /**
384 | * Left join with complex conditions.
385 | *
386 | * @param string|array $table Table name
387 | * @param string $conditions The ON conditions e.g. 'user.id = article.user_id'
388 | *
389 | * @return self
390 | */
391 | public function leftJoinRaw($table, string $conditions): self
392 | {
393 | $this->join[] = ['left', $table, new RawExp($conditions), null, null, null];
394 |
395 | return $this;
396 | }
397 |
398 | /**
399 | * Where AND condition.
400 | *
401 | * @param array ...$conditions The conditions (field, comparison, value)
402 | * or (field, comparison, new RawExp('table.field'))
403 | * or new RawExp('...')
404 | *
405 | * @return self
406 | */
407 | public function where(...$conditions): self
408 | {
409 | $this->condition->where($conditions);
410 |
411 | return $this;
412 | }
413 |
414 | /**
415 | * Add a raw AND WHERE condition.
416 | *
417 | * @param string $condition The raw where conditions e.g. 'user.id = article.user_id'
418 | *
419 | * @return self
420 | */
421 | public function whereRaw(string $condition): self
422 | {
423 | $this->condition->where([new RawExp($condition)]);
424 |
425 | return $this;
426 | }
427 |
428 | /**
429 | * Where OR condition.
430 | *
431 | * @param array ...$conditions The conditions (field, comparison, value)
432 | * or (field, comparison, new RawExp('table.field'))
433 | * or new RawExp('...')
434 | *
435 | * @return self
436 | */
437 | public function orWhere(...$conditions): self
438 | {
439 | $this->condition->orWhere($conditions);
440 |
441 | return $this;
442 | }
443 |
444 | /**
445 | * Add a raw OR WHERE condition.
446 | *
447 | * @param string $condition The raw where conditions e.g. 'user.id = article.user_id'
448 | *
449 | * @return self
450 | */
451 | public function orWhereRaw(string $condition): self
452 | {
453 | $this->condition->orWhere([new RawExp($condition)]);
454 |
455 | return $this;
456 | }
457 |
458 | /**
459 | * The whereColumn method may be used to verify that two columns are equal.
460 | *
461 | * @param string $column Name of the first column
462 | * @param string $comparison The comparison type (=,>=,<=,<>,is,is not, ....)
463 | * @param string $secondColumn Name of the second column
464 | *
465 | * @return self
466 | */
467 | public function whereColumn(string $column, string $comparison, string $secondColumn): self
468 | {
469 | $secondColumn = $this->quoter->quoteName($secondColumn);
470 | $this->condition->where([$column, $comparison, new RawExp($secondColumn)]);
471 |
472 | return $this;
473 | }
474 |
475 | /**
476 | * The whereColumn method may be used to verify that two columns are equal.
477 | *
478 | * @param string $column Name of the first column
479 | * @param string $comparison The comparison (=,>=,<=,<>,is,is not, ....)
480 | * @param string $secondColumn Name of the second column
481 | *
482 | * @return self
483 | */
484 | public function orWhereColumn(string $column, string $comparison, string $secondColumn): self
485 | {
486 | $secondColumn = $this->quoter->quoteName($secondColumn);
487 | $this->condition->orWhere([$column, $comparison, new RawExp($secondColumn)]);
488 |
489 | return $this;
490 | }
491 |
492 | /**
493 | * Order by.
494 | *
495 | * @param array ...$fields Column name(s)
496 | *
497 | * @return self
498 | */
499 | public function orderBy(...$fields): self
500 | {
501 | $this->orderBy = $fields;
502 |
503 | return $this;
504 | }
505 |
506 | /**
507 | * Group by.
508 | *
509 | * @param array ...$fields The fields
510 | *
511 | * @return self
512 | */
513 | public function groupBy(...$fields): self
514 | {
515 | $this->groupBy = $fields;
516 |
517 | return $this;
518 | }
519 |
520 | /**
521 | * Add AND having condition.
522 | *
523 | * @param array ...$conditions The conditions (field, comparison, value)
524 | * or (field, comparison, new RawExp('table.field'))
525 | * or new RawExp('...')
526 | *
527 | * @return self
528 | */
529 | public function having(...$conditions): self
530 | {
531 | $this->condition->having($conditions);
532 |
533 | return $this;
534 | }
535 |
536 | /**
537 | * Add OR having condition.
538 | *
539 | * @param array ...$conditions The conditions (field, comparison, value)
540 | * or (field, comparison, new RawExp('table.field'))
541 | * or new RawExp('...')
542 | *
543 | * @return self
544 | */
545 | public function orHaving(...$conditions): self
546 | {
547 | $this->condition->orHaving($conditions);
548 |
549 | return $this;
550 | }
551 |
552 | /**
553 | * Add AND having condition.
554 | *
555 | * @param string $condition The raw HAVING conditions e.g. 'user.id = article.user_id'
556 | *
557 | * @return self
558 | */
559 | public function havingRaw(string $condition): self
560 | {
561 | $this->condition->having([new RawExp($condition)]);
562 |
563 | return $this;
564 | }
565 |
566 | /**
567 | * Add OR having condition.
568 | *
569 | * @param string $condition The raw HAVING conditions e.g. 'user.id = article.user_id'
570 | *
571 | * @return self
572 | */
573 | public function orHavingRaw(string $condition): self
574 | {
575 | $this->condition->orHaving([new RawExp($condition)]);
576 |
577 | return $this;
578 | }
579 |
580 | /**
581 | * Limit the number of rows returned.
582 | *
583 | * @param int $rowCount Row count
584 | *
585 | * @return self
586 | */
587 | public function limit(int $rowCount): self
588 | {
589 | $this->limit = $rowCount;
590 |
591 | return $this;
592 | }
593 |
594 | /**
595 | * Offset of the first row to return.
596 | *
597 | * @param int $offset Offset
598 | *
599 | * @return self
600 | */
601 | public function offset(int $offset): self
602 | {
603 | $this->offset = $offset;
604 |
605 | return $this;
606 | }
607 |
608 | /**
609 | * Returns a Raw Expression.
610 | *
611 | * @param string $value A raw value. Be careful!
612 | *
613 | * @return RawExp Raw Expression
614 | */
615 | public function raw(string $value): RawExp
616 | {
617 | return new RawExp($value);
618 | }
619 |
620 | /**
621 | * Executes an SQL statement, returning a result set as a PDOStatement object.
622 | *
623 | * @throws RuntimeException
624 | *
625 | * @return PDOStatement The pdo statement
626 | */
627 | public function execute(): PDOStatement
628 | {
629 | $statement = $this->pdo->query($this->build());
630 |
631 | if (!$statement instanceof PDOStatement) {
632 | throw new RuntimeException('Query could not be created');
633 | }
634 |
635 | return $statement;
636 | }
637 |
638 | /**
639 | * Prepares a statement for execution and returns a statement object.
640 | *
641 | * @throws RuntimeException
642 | *
643 | * @return PDOStatement The pdo statement
644 | */
645 | public function prepare(): PDOStatement
646 | {
647 | $statement = $this->pdo->prepare($this->build());
648 |
649 | if (!$statement instanceof PDOStatement) {
650 | throw new RuntimeException('The database statement could not be prepared.');
651 | }
652 |
653 | return $statement;
654 | }
655 |
656 | /**
657 | * SQL functions.
658 | *
659 | * @return FunctionBuilder The function builder
660 | */
661 | public function func(): FunctionBuilder
662 | {
663 | return new FunctionBuilder($this->connection);
664 | }
665 |
666 | /**
667 | * Build a SQL string.
668 | *
669 | * @param bool $complete The complete
670 | *
671 | * @return string SQL string
672 | */
673 | public function build(bool $complete = true): string
674 | {
675 | $builder = new SelectQueryBuilder($this->connection);
676 |
677 | $sql = [];
678 | $sql = $builder->getSelectSql(
679 | $sql,
680 | [
681 | $this->distinct,
682 | $this->highPriority,
683 | $this->straightJoin,
684 | $this->resultSize,
685 | $this->bufferResult,
686 | $this->calcFoundRows,
687 | ]
688 | );
689 | $sql = $builder->getColumnsSql($sql, $this->columns);
690 | $sql = $builder->getFromSql($sql, $this->from);
691 | $sql = $builder->getJoinSql($sql, $this->join);
692 | $sql = $this->condition->getWhereSql($sql);
693 | $sql = $builder->getGroupBySql($sql, $this->groupBy);
694 | $sql = $this->condition->getHavingSql($sql);
695 | $sql = $builder->getOrderBySql($sql, $this->orderBy);
696 | $sql = $builder->getLimitSql($sql, $this->limit, $this->offset);
697 | $sql = $builder->getUnionSql($sql, $this->union);
698 | $result = trim(implode(' ', $sql));
699 | $result = $builder->getAliasSql($result, $this->alias);
700 |
701 | if ($complete) {
702 | $result = trim($result) . ';';
703 | }
704 |
705 | return $result;
706 | }
707 | }
708 |
--------------------------------------------------------------------------------
/src/SelectQueryBuilder.php:
--------------------------------------------------------------------------------
1 | connection = $connection;
30 | $this->quoter = $connection->getQuoter();
31 | }
32 |
33 | /**
34 | * Get sql.
35 | *
36 | * @param array $sql The sql
37 | * @param array $options The options
38 | *
39 | * @return array The sql
40 | */
41 | public function getSelectSql(array $sql, array $options = []): array
42 | {
43 | $sql[] = trim('SELECT ' . trim(implode(' ', $options)));
44 |
45 | return $sql;
46 | }
47 |
48 | /**
49 | * Get sql.
50 | *
51 | * @param array $sql The sql
52 | * @param array $inputColumns The input columns
53 | *
54 | * @return array The sql
55 | */
56 | public function getColumnsSql(array $sql, array $inputColumns): array
57 | {
58 | if (empty($inputColumns)) {
59 | $sql[] = '*';
60 |
61 | return $sql;
62 | }
63 | $columns = [];
64 | foreach ($inputColumns as $key => $column) {
65 | if ($column instanceof Closure) {
66 | // Sub Select
67 | $query = new SelectQuery($this->connection);
68 | $column($query);
69 | $column = new RawExp($query->build(false));
70 | }
71 |
72 | if (!is_int($key)) {
73 | // Column with alias as array
74 | $column = [$key => $column];
75 | }
76 |
77 | $columns[] = $column;
78 | }
79 | $sql[] = implode(',', $this->quoter->quoteNames($columns));
80 |
81 | return $sql;
82 | }
83 |
84 | /**
85 | * Get sql.
86 | *
87 | * @param array $sql The sql
88 | * @param string|array $from The table
89 | *
90 | * @return array The sql
91 | */
92 | public function getFromSql(array $sql, $from): array
93 | {
94 | if (!empty($from)) {
95 | $sql[] = 'FROM ' . $this->quoter->quoteName($from);
96 | }
97 |
98 | return $sql;
99 | }
100 |
101 | /**
102 | * Get sql.
103 | *
104 | * @param array $sql The sql
105 | * @param array|null $join The join
106 | *
107 | * @return array The sql
108 | */
109 | public function getJoinSql(array $sql, array $join = null): array
110 | {
111 | if (empty($join)) {
112 | return $sql;
113 | }
114 | foreach ($join as $item) {
115 | [$type, $table, $leftField, $operator, $rightField] = $item;
116 | $joinType = strtoupper($type) . ' JOIN';
117 | $table = $this->quoter->quoteName($table);
118 | if ($leftField instanceof RawExp) {
119 | $sql[] = sprintf('%s %s ON (%s)', $joinType, $table, $leftField->getValue());
120 | } else {
121 | $leftField = $this->quoter->quoteName($leftField);
122 | $rightField = $this->quoter->quoteName($rightField);
123 | $sql[] = sprintf('%s %s ON %s %s %s', $joinType, $table, $leftField, $operator, $rightField);
124 | }
125 | }
126 |
127 | return $sql;
128 | }
129 |
130 | /**
131 | * Get sql.
132 | *
133 | * @param array $sql The sql
134 | * @param array $groupBy The group by
135 | *
136 | * @return array The sql
137 | */
138 | public function getGroupBySql(array $sql, array $groupBy): array
139 | {
140 | if (empty($groupBy)) {
141 | return $sql;
142 | }
143 | $sql[] = 'GROUP BY ' . implode(', ', $this->quoter->quoteByFields($groupBy));
144 |
145 | return $sql;
146 | }
147 |
148 | /**
149 | * Get sql.
150 | *
151 | * @param array $sql The sql
152 | * @param array|null $orderBy The order
153 | *
154 | * @return array The sql
155 | */
156 | public function getOrderBySql(array $sql, array $orderBy = null): array
157 | {
158 | if (empty($orderBy)) {
159 | return $sql;
160 | }
161 | $sql[] = 'ORDER BY ' . implode(', ', $this->quoter->quoteByFields($orderBy));
162 |
163 | return $sql;
164 | }
165 |
166 | /**
167 | * Get sql.
168 | *
169 | * @param array $sql The sql
170 | * @param int|null $limit The limit
171 | * @param int|null $offset The offset
172 | *
173 | * @return array The sql
174 | */
175 | public function getLimitSql(array $sql, int $limit = null, int $offset = null): array
176 | {
177 | if (!isset($limit)) {
178 | return $sql;
179 | }
180 | if ($offset > 0) {
181 | $sql[] = sprintf('LIMIT %s OFFSET %s', $limit, $offset);
182 | } else {
183 | $sql[] = sprintf('LIMIT %s', $limit);
184 | }
185 |
186 | return $sql;
187 | }
188 |
189 | /**
190 | * Get sql.
191 | *
192 | * @param array $sql The sql
193 | * @param array|null $unions The unions
194 | *
195 | * @return array The sql
196 | */
197 | public function getUnionSql(array $sql, array $unions = null): array
198 | {
199 | if (empty($unions)) {
200 | return $sql;
201 | }
202 | foreach ($unions as $union) {
203 | $sql[] = 'UNION ' . trim($union[0] . ' ' . $union[1]);
204 | }
205 |
206 | return $sql;
207 | }
208 |
209 | /**
210 | * Get sql.
211 | *
212 | * @param string $sql The sql
213 | * @param string|null $alias The alias
214 | *
215 | * @return string $sql The sql
216 | */
217 | public function getAliasSql(string $sql, string $alias = null): string
218 | {
219 | if (!isset($alias)) {
220 | return $sql;
221 | }
222 |
223 | return sprintf('(%s) AS %s', $sql, $this->quoter->quoteName($alias));
224 | }
225 | }
226 |
--------------------------------------------------------------------------------
/src/UpdateQuery.php:
--------------------------------------------------------------------------------
1 | pdo = $connection->getPdo();
71 | $this->quoter = $connection->getQuoter();
72 | $this->condition = new Condition($connection, $this);
73 | }
74 |
75 | /**
76 | * Priority modifier.
77 | *
78 | * @return self
79 | */
80 | public function lowPriority(): self
81 | {
82 | $this->priority = 'LOW_PRIORITY';
83 |
84 | return $this;
85 | }
86 |
87 | /**
88 | * Ignore errors modifier.
89 | *
90 | * @return self
91 | */
92 | public function ignore(): self
93 | {
94 | $this->ignore = 'IGNORE';
95 |
96 | return $this;
97 | }
98 |
99 | /**
100 | * Table name.
101 | *
102 | * @param string $table Table name
103 | *
104 | * @return self
105 | */
106 | public function table(string $table): self
107 | {
108 | $this->table = $table;
109 |
110 | return $this;
111 | }
112 |
113 | /**
114 | * Values (key value).
115 | *
116 | * @param array $values The values
117 | *
118 | * @return self
119 | */
120 | public function set(array $values): self
121 | {
122 | $this->values = $values;
123 |
124 | return $this;
125 | }
126 |
127 | /**
128 | * Where AND condition.
129 | *
130 | * @param array ...$conditions The conditions (field, comparison, value)
131 | * or (field, comparison, new RawExp('table.field'))
132 | * or new RawExp('...')
133 | *
134 | * @return self
135 | */
136 | public function where(...$conditions): self
137 | {
138 | $this->condition->where($conditions);
139 |
140 | return $this;
141 | }
142 |
143 | /**
144 | * Where OR condition.
145 | *
146 | * @param array ...$conditions The conditions (field, comparison, value)
147 | * or (field, comparison, new RawExp('table.field'))
148 | * or new RawExp('...')
149 | *
150 | * @return self
151 | */
152 | public function orWhere(...$conditions): self
153 | {
154 | $this->condition->orWhere($conditions);
155 |
156 | return $this;
157 | }
158 |
159 | /**
160 | * Order by.
161 | *
162 | * @param array ...$fields Column name(s)
163 | *
164 | * @return self
165 | */
166 | public function orderBy(...$fields): self
167 | {
168 | $this->orderBy = $fields;
169 |
170 | return $this;
171 | }
172 |
173 | /**
174 | * Limit the number of rows returned.
175 | *
176 | * @param int $rowCount Row count
177 | *
178 | * @return self
179 | */
180 | public function limit(int $rowCount): self
181 | {
182 | $this->limit = $rowCount;
183 |
184 | return $this;
185 | }
186 |
187 | /**
188 | * Incrementing or decrementing the value of a given column.
189 | *
190 | * @param string $column The column to modify
191 | * @param int $amount The amount by which the column should be incremented [optional]
192 | *
193 | * @return self
194 | */
195 | public function increment(string $column, int $amount = 1): self
196 | {
197 | $this->values[$column] = new RawExp(
198 | $this->quoter->quoteName($column) .
199 | '+' .
200 | $this->quoter->quoteValue($amount)
201 | );
202 |
203 | return $this;
204 | }
205 |
206 | /**
207 | * Decrementing the value of a given column.
208 | *
209 | * @param string $column The column to modify
210 | * @param int $amount The amount by which the column should be decrement [optional]
211 | *
212 | * @return self
213 | */
214 | public function decrement(string $column, int $amount = 1): self
215 | {
216 | $this->values[$column] = new RawExp(
217 | $this->quoter->quoteName($column) . '-' . $this->quoter->quoteValue($amount)
218 | );
219 |
220 | return $this;
221 | }
222 |
223 | /**
224 | * Executes a prepared statement.
225 | *
226 | * @return bool Success
227 | */
228 | public function execute(): bool
229 | {
230 | return $this->prepare()->execute();
231 | }
232 |
233 | /**
234 | * Prepares a statement for execution and returns a statement object.
235 | *
236 | * @throws RuntimeException
237 | *
238 | * @return PDOStatement The PDOStatement
239 | */
240 | public function prepare(): PDOStatement
241 | {
242 | $statement = $this->pdo->prepare($this->build());
243 |
244 | if (!$statement instanceof PDOStatement) {
245 | throw new RuntimeException('The database statement could not be prepared.');
246 | }
247 |
248 | return $statement;
249 | }
250 |
251 | /**
252 | * Build a SQL string.
253 | *
254 | * @return string SQL string
255 | */
256 | public function build(): string
257 | {
258 | $sql = [];
259 | $sql = $this->getUpdateSql($sql);
260 | $sql = $this->getSetSql($sql);
261 | $sql = $this->condition->getWhereSql($sql);
262 | $sql = $this->getOrderBySql($sql);
263 | $sql = $this->getLimitSql($sql);
264 |
265 | return trim(implode(' ', $sql)) . ';';
266 | }
267 |
268 | /**
269 | * Get sql.
270 | *
271 | * @param array $sql The sql
272 | *
273 | * @return array The sql
274 | */
275 | private function getUpdateSql(array $sql): array
276 | {
277 | $update = 'UPDATE';
278 | if (!empty($this->priority)) {
279 | $update .= ' ' . $this->priority;
280 | }
281 | if (!empty($this->ignore)) {
282 | $update .= ' ' . $this->ignore;
283 | }
284 | $sql[] = $update . ' ' . $this->quoter->quoteName($this->table);
285 |
286 | return $sql;
287 | }
288 |
289 | /**
290 | * Get sql.
291 | *
292 | * @param array $sql The sql
293 | *
294 | * @return array The sql
295 | */
296 | private function getSetSql(array $sql): array
297 | {
298 | // single row
299 | $sql[] = 'SET ' . $this->quoter->quoteSetValues($this->values);
300 |
301 | return $sql;
302 | }
303 |
304 | /**
305 | * Get sql.
306 | *
307 | * @param array $sql The sql
308 | *
309 | * @return array The sql
310 | */
311 | private function getOrderBySql(array $sql): array
312 | {
313 | if (empty($this->orderBy)) {
314 | return $sql;
315 | }
316 | $sql[] = 'ORDER BY ' . implode(', ', $this->quoter->quoteByFields($this->orderBy));
317 |
318 | return $sql;
319 | }
320 |
321 | /**
322 | * Get sql.
323 | *
324 | * @param array $sql The sql
325 | *
326 | * @return array The sql
327 | */
328 | private function getLimitSql(array $sql): array
329 | {
330 | if (!isset($this->limit)) {
331 | return $sql;
332 | }
333 | $sql[] = sprintf('LIMIT %s', $this->limit);
334 |
335 | return $sql;
336 | }
337 | }
338 |
--------------------------------------------------------------------------------
/tests/BaseTest.php:
--------------------------------------------------------------------------------
1 | getConnection();
31 | $pdo = $db->getPdo();
32 |
33 | $sql = "SELECT SCHEMA_NAME FROM INFORMATION_SCHEMA.SCHEMATA WHERE SCHEMA_NAME = 'database_test';";
34 | $statement = $pdo->query($sql);
35 |
36 | if ($statement === false) {
37 | throw new UnexpectedValueException('Query failed');
38 | }
39 |
40 | $statement->execute();
41 |
42 | if (!$statement->fetch(PDO::FETCH_ASSOC)) {
43 | $pdo->exec('CREATE DATABASE database_test CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;');
44 | }
45 |
46 | $pdo->exec('USE database_test');
47 | $pdo->exec('DROP TABLE IF EXISTS test;');
48 |
49 | $db->getPdo()->exec(
50 | 'CREATE TABLE `test` (
51 | `id` INT(11) NOT NULL AUTO_INCREMENT,
52 | `keyname` VARCHAR(255) COLLATE utf8_unicode_ci,
53 | `keyvalue` VARCHAR(255) COLLATE utf8_unicode_ci,
54 | `boolvalue` TINYINT(1) NOT NULL DEFAULT 0,
55 | `created` DATETIME DEFAULT NULL,
56 | `created_user_id` INT(11) DEFAULT NULL,
57 | `updated` DATETIME DEFAULT NULL,
58 | `updated_user_id` INT(11) DEFAULT NULL,
59 | PRIMARY KEY (`id`),
60 | KEY `created_user_id` (`created_user_id`),
61 | KEY `updated_user_id` (`updated_user_id`)
62 | ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;'
63 | );
64 | }
65 |
66 | /**
67 | * Get PDO.
68 | *
69 | * @return PDO The connection
70 | */
71 | protected function getPdo(): PDO
72 | {
73 | $host = '127.0.0.1';
74 | $username = 'root';
75 | $password = isset($_SERVER['GITHUB_ACTIONS']) ? 'root' : '';
76 | $charset = 'utf8mb4';
77 | $collate = 'utf8mb4_unicode_ci';
78 | $options = [
79 | PDO::ATTR_ERRMODE => PDO::ERRMODE_EXCEPTION,
80 | PDO::ATTR_PERSISTENT => false,
81 | PDO::ATTR_DEFAULT_FETCH_MODE => PDO::FETCH_ASSOC,
82 | PDO::MYSQL_ATTR_INIT_COMMAND => "SET NAMES $charset COLLATE $collate",
83 | ];
84 |
85 | return new PDO("mysql:host=$host;charset=$charset", $username, $password, $options);
86 | }
87 |
88 | /**
89 | * Get connection.
90 | *
91 | * @return Connection The connection
92 | */
93 | protected function getConnection(): Connection
94 | {
95 | if ($this->connection === null) {
96 | $this->connection = new Connection($this->getPdo());
97 | }
98 |
99 | return $this->connection;
100 | }
101 |
102 | /**
103 | * @return SelectQuery
104 | */
105 | protected function select(): SelectQuery
106 | {
107 | return new SelectQuery($this->getConnection());
108 | }
109 | }
110 |
--------------------------------------------------------------------------------
/tests/ConnectionTest.php:
--------------------------------------------------------------------------------
1 | getConnection();
23 | $this->assertInstanceOf(Connection::class, $connection);
24 | }
25 |
26 | /**
27 | * Test.
28 | */
29 | public function testPrepareQuery(): void
30 | {
31 | $select = $this->select();
32 | $select->columns(['TABLE_NAME'])
33 | ->from('information_schema.TABLES')
34 | ->where('TABLE_NAME', '=', 'TABLES');
35 |
36 | $statement = $select->prepare();
37 |
38 | $statement->execute();
39 |
40 | /** @var array $row */
41 | $row = $statement->fetch(PDO::FETCH_ASSOC);
42 |
43 | $this->assertNotEmpty($row['TABLE_NAME']);
44 | $this->assertSame('TABLES', $row['TABLE_NAME']);
45 | }
46 | }
47 |
--------------------------------------------------------------------------------
/tests/DeleteQueryTest.php:
--------------------------------------------------------------------------------
1 | assertInstanceOf(DeleteQuery::class, $this->delete());
20 | }
21 |
22 | /**
23 | * @return DeleteQuery
24 | */
25 | protected function delete(): DeleteQuery
26 | {
27 | return new DeleteQuery($this->getConnection());
28 | }
29 |
30 | /**
31 | * Test.
32 | */
33 | public function testFrom(): void
34 | {
35 | $delete = $this->delete()->from('test');
36 | $this->assertSame('DELETE FROM `test`;', $delete->build());
37 | $this->assertTrue($delete->execute());
38 | }
39 |
40 | /**
41 | * Test.
42 | */
43 | public function testLowPriority(): void
44 | {
45 | $delete = $this->delete()->lowPriority()->from('test');
46 | $this->assertSame('DELETE LOW_PRIORITY FROM `test`;', $delete->build());
47 | }
48 |
49 | /**
50 | * Test.
51 | */
52 | public function testIgnore(): void
53 | {
54 | $delete = $this->delete()->ignore()->from('test')->where('id', '=', '1');
55 | $this->assertSame("DELETE IGNORE FROM `test` WHERE `id` = '1';", $delete->build());
56 |
57 | $delete = $this->delete()->lowPriority()->ignore()->from('test')->where('id', '=', '1');
58 | $this->assertSame("DELETE LOW_PRIORITY IGNORE FROM `test` WHERE `id` = '1';", $delete->build());
59 | }
60 |
61 | /**
62 | * Test.
63 | */
64 | public function testQuick(): void
65 | {
66 | $delete = $this->delete()->quick()->from('test')->where('id', '=', '1');
67 | $this->assertSame("DELETE QUICK FROM `test` WHERE `id` = '1';", $delete->build());
68 | }
69 |
70 | /**
71 | * Test.
72 | */
73 | public function testOrderBy(): void
74 | {
75 | $delete = $this->delete()->from('test')->where('id', '=', '1')->orderBy('id');
76 | $this->assertSame("DELETE FROM `test` WHERE `id` = '1' ORDER BY `id`;", $delete->build());
77 |
78 | $delete = $this->delete()->from('test')->where('id', '=', '1')->orderBy('id DESC');
79 | $this->assertSame("DELETE FROM `test` WHERE `id` = '1' ORDER BY `id` DESC;", $delete->build());
80 |
81 | $delete = $this->delete()->from('test')->where('id', '=', '1')->orderBy('test.id ASC');
82 | $this->assertSame("DELETE FROM `test` WHERE `id` = '1' ORDER BY `test`.`id` ASC;", $delete->build());
83 |
84 | $delete = $this->delete()->from('test')->where('id', '=', '1')->orderBy('db.test.id ASC');
85 | $this->assertSame("DELETE FROM `test` WHERE `id` = '1' ORDER BY `db`.`test`.`id` ASC;", $delete->build());
86 | }
87 |
88 | /**
89 | * Test.
90 | */
91 | public function testLimit(): void
92 | {
93 | $delete = $this->delete()->from('test')->where('id', '>', '1')->limit(10);
94 | $this->assertSame("DELETE FROM `test` WHERE `id` > '1' LIMIT 10;", $delete->build());
95 | }
96 |
97 | /**
98 | * Test.
99 | */
100 | public function testWhere(): void
101 | {
102 | $delete = $this->delete()->from('test')->where('id', '=', '1')
103 | ->where('test.id', '=', 1)
104 | ->orWhere('db.test.id', '>', 2);
105 | $this->assertSame(
106 | "DELETE FROM `test` WHERE `id` = '1' AND `test`.`id` = '1' OR `db`.`test`.`id` > '2';",
107 | $delete->build()
108 | );
109 | }
110 |
111 | /**
112 | * Test.
113 | */
114 | public function testTruncate(): void
115 | {
116 | $delete = $this->delete()->from('test')->truncate();
117 | $this->assertSame('TRUNCATE TABLE `test`;', $delete->build());
118 | }
119 |
120 | /**
121 | * Setup.
122 | */
123 | protected function setUp(): void
124 | {
125 | parent::setUp();
126 | $this->createTestTable();
127 | }
128 | }
129 |
--------------------------------------------------------------------------------
/tests/FunctionBuilderTest.php:
--------------------------------------------------------------------------------
1 | getConnection()->select()->func();
24 | $this->assertInstanceOf(FunctionBuilder::class, $func);
25 | }
26 |
27 | /**
28 | * Test.
29 | *
30 | * @return void
31 | */
32 | public function testSum()
33 | {
34 | $func = $this->getConnection()->select()->func();
35 |
36 | $this->assertEquals('SUM(`field`)', $func->sum('field'));
37 | $this->assertEquals('SUM(`table`.`field`)', $func->sum('table.field'));
38 |
39 | $query = $this->getConnection()->select()->from('payments');
40 | $query->columns([$query->func()->count('amount')]);
41 | $this->assertEquals('SELECT COUNT(`amount`) FROM `payments`;', $query->build());
42 | }
43 |
44 | /**
45 | * Test.
46 | *
47 | * @return void
48 | */
49 | public function testAvg(): void
50 | {
51 | $func = $this->getConnection()->select()->func();
52 |
53 | $this->assertEquals('AVG(`field`)', $func->avg('field'));
54 | $this->assertEquals('AVG(`table`.`field`)', $func->avg('table.field'));
55 | }
56 |
57 | /**
58 | * Test.
59 | *
60 | * @return void
61 | */
62 | public function testMin(): void
63 | {
64 | $func = $this->getConnection()->select()->func();
65 |
66 | $this->assertEquals('MIN(`field`)', $func->min('field'));
67 | $this->assertEquals('MIN(`table`.`field`)', $func->min('table.field'));
68 | }
69 |
70 | /**
71 | * Test.
72 | *
73 | * @return void
74 | */
75 | public function testMax(): void
76 | {
77 | $func = $this->getConnection()->select()->func();
78 |
79 | $this->assertEquals('MAX(`field`)', $func->max('field'));
80 | $this->assertEquals('MAX(`table`.`field`)', $func->max('table.field'));
81 | }
82 |
83 | /**
84 | * Test.
85 | *
86 | * @return void
87 | */
88 | public function testCount(): void
89 | {
90 | $func = $this->getConnection()->select()->func();
91 |
92 | $this->assertEquals('COUNT(*)', $func->count());
93 | $this->assertEquals('COUNT(`field`)', $func->count('field'));
94 | $this->assertEquals('COUNT(`field`) AS `alias_field`', $func->count('field')->alias('alias_field'));
95 |
96 | $query = $this->getConnection()->select()->from('users');
97 | $query->columns([$query->func()->count()]);
98 | $this->assertEquals('SELECT COUNT(*) FROM `users`;', $query->build());
99 | }
100 |
101 | /**
102 | * Test.
103 | *
104 | * @return void
105 | */
106 | public function testNow(): void
107 | {
108 | $func = $this->getConnection()->select()->func();
109 |
110 | $this->assertInstanceOf(RawExp::class, $func->now());
111 | $this->assertEquals('NOW()', $func->now());
112 | $this->assertEquals('NOW() AS `alias_field`', $func->now()->alias('alias_field')->getValue());
113 | }
114 |
115 | /**
116 | * Test.
117 | *
118 | * @return void
119 | */
120 | public function testCustom(): void
121 | {
122 | $query = $this->getConnection()->select();
123 | $func = $query->func();
124 |
125 | // Only values
126 | $function = $func->call('ifnull', null, 'test')->alias('alias_field');
127 | $this->assertInstanceOf(FunctionExpression::class, $function);
128 | $this->assertEquals("IFNULL(NULL, 'test') AS `alias_field`", $function->getValue());
129 |
130 | // only values
131 | $function = $func->call('repeat', 'a', 1000);
132 | $this->assertEquals("REPEAT('a', '1000')", $function->getValue());
133 |
134 | // with fields
135 | $function = $func->call('ifnull', $func->field('users.email'), 'test');
136 | $this->assertEquals("IFNULL(`users`.`email`, 'test')", $function->getValue());
137 |
138 | // Full query
139 | $query->columns(
140 | [
141 | $func->call(
142 | 'concat',
143 | $func->field('users.first_name'),
144 | '-',
145 | $func->field('users.last_name')
146 | ),
147 | ]
148 | );
149 | $query->from('users');
150 |
151 | $this->assertEquals(
152 | "SELECT CONCAT(`users`.`first_name`, '-', `users`.`last_name`) FROM `users`;",
153 | $query->build()
154 | );
155 |
156 | // nested functions
157 | $query = $this->getConnection()->select();
158 | $func = $query->func();
159 |
160 | $query->columns([$func->call('length', $func->call('compress', "a'b"))->alias('l')]);
161 | $this->assertEquals("SELECT LENGTH(COMPRESS('a\'b')) AS `l`;", $query->build());
162 | }
163 | }
164 |
--------------------------------------------------------------------------------
/tests/InsertQueryTest.php:
--------------------------------------------------------------------------------
1 | createTestTable();
21 | }
22 |
23 | /**
24 | * Test create object.
25 | *
26 | * @return void
27 | */
28 | public function testInstance(): void
29 | {
30 | $this->assertInstanceOf(InsertQuery::class, $this->insert());
31 | }
32 |
33 | /**
34 | * Create insert.
35 | *
36 | * @return InsertQuery The query
37 | */
38 | protected function insert(): InsertQuery
39 | {
40 | return new InsertQuery($this->getConnection());
41 | }
42 |
43 | /**
44 | * Test.
45 | *
46 | * @return void
47 | */
48 | public function testInto(): void
49 | {
50 | $insert = $this->insert()->into('test')->set(['keyname' => 'admin-007']);
51 | $this->assertSame("INSERT INTO `test` SET `keyname`='admin-007';", $insert->build());
52 | $stmt = $insert->prepare();
53 | $this->assertTrue($stmt->execute());
54 | $this->assertSame(1, $stmt->rowCount());
55 | $this->assertSame('1', $this->getConnection()->getPdo()->lastInsertId());
56 | }
57 |
58 | /**
59 | * Test.
60 | *
61 | * @return void
62 | */
63 | public function testLastInsertId(): void
64 | {
65 | $insert = $this->insert()->into('test')->set(['keyname' => 'admin-007']);
66 | $insert->execute();
67 | $this->assertSame('1', $insert->lastInsertId());
68 | }
69 |
70 | /**
71 | * Test.
72 | *
73 | * @return void
74 | */
75 | public function testInsertGetId(): void
76 | {
77 | $insertGetId = $this->insert()->into('test')->insertGetId(['keyname' => 'admin-007']);
78 | $this->assertSame('1', $insertGetId);
79 | }
80 |
81 | /**
82 | * Test.
83 | *
84 | * @return void
85 | */
86 | public function testPriority(): void
87 | {
88 | $insert = $this->insert()->lowPriority()->into('test')->set(['username' => 'admin']);
89 | $this->assertSame("INSERT LOW_PRIORITY INTO `test` SET `username`='admin';", $insert->build());
90 |
91 | $insert = $this->insert()->highPriority()->into('test')->set(['username' => 'admin']);
92 | $this->assertSame("INSERT HIGH_PRIORITY INTO `test` SET `username`='admin';", $insert->build());
93 | }
94 |
95 | /**
96 | * Test.
97 | *
98 | * @return void
99 | */
100 | public function testIgnore(): void
101 | {
102 | $insert = $this->insert()->ignore()->into('test')->set(['username' => 'admin']);
103 | $this->assertSame("INSERT IGNORE INTO `test` SET `username`='admin';", $insert->build());
104 |
105 | $insert = $this->insert()->lowPriority()->ignore()->into('test')->set(['username' => 'admin']);
106 | $this->assertSame("INSERT LOW_PRIORITY IGNORE INTO `test` SET `username`='admin';", $insert->build());
107 | }
108 |
109 | /**
110 | * Test.
111 | *
112 | * @return void
113 | */
114 | public function testDelayed(): void
115 | {
116 | $insert = $this->insert()->delayed()->into('test')->set(['username' => 'admin']);
117 | $this->assertSame("INSERT DELAYED INTO `test` SET `username`='admin';", $insert->build());
118 | }
119 |
120 | /**
121 | * Test.
122 | *
123 | * @return void
124 | */
125 | public function testOnDuplicateKeyUpdate(): void
126 | {
127 | $insert = $this->insert()->ignore()->into('test')->set(['username' => 'admin']);
128 | $insert->onDuplicateKeyUpdate(['username' => 'admin-01']);
129 | $this->assertSame(
130 | "INSERT IGNORE INTO `test` SET `username`='admin' " .
131 | "ON DUPLICATE KEY UPDATE `username`='admin-01';",
132 | $insert->build()
133 | );
134 | }
135 | }
136 |
--------------------------------------------------------------------------------
/tests/QuoterTest.php:
--------------------------------------------------------------------------------
1 | getConnection()->getQuoter();
23 | $this->assertInstanceOf(Quoter::class, $connection);
24 | }
25 |
26 | /**
27 | * Test.
28 | *
29 | * @return void
30 | */
31 | public function testEsc(): void
32 | {
33 | $quoter = $this->getConnection()->getQuoter();
34 | $this->assertSame('NULL', $quoter->quoteValue(null));
35 | $this->assertSame("'\\0'", $quoter->quoteValue("\0"));
36 | $this->assertSame("'0'", $quoter->quoteValue(0));
37 | $this->assertSame("'0'", $quoter->quoteValue('0'));
38 | $this->assertSame("''", $quoter->quoteValue(false));
39 | $this->assertSame("'1'", $quoter->quoteValue(true));
40 | $this->assertSame("'-1'", $quoter->quoteValue(-1));
41 | $this->assertSame("'abc123'", $quoter->quoteValue('abc123'));
42 | $this->assertSame("'öäüÖÄÜß'", $quoter->quoteValue('öäüÖÄÜß'));
43 | $this->assertSame("'?'", $quoter->quoteValue('?'));
44 | $this->assertSame("':'", $quoter->quoteValue(':'));
45 | $this->assertSame("'\\''", $quoter->quoteValue("'"));
46 | $this->assertSame("'\\\"'", $quoter->quoteValue('"'));
47 | $this->assertSame("'\\\\'", $quoter->quoteValue('\\'));
48 | $this->assertSame("'\\0'", $quoter->quoteValue("\x00"));
49 | $this->assertSame("'\\Z'", $quoter->quoteValue("\x1a"));
50 | $this->assertSame("'\\n'", $quoter->quoteValue("\n"));
51 | $this->assertSame("'\\r'", $quoter->quoteValue("\r"));
52 | $this->assertSame("','", $quoter->quoteValue(','));
53 | $this->assertSame("'\\','", $quoter->quoteValue("',"));
54 | $this->assertSame("'`'", $quoter->quoteValue('`'));
55 | $this->assertSame("'%s'", $quoter->quoteValue('%s'));
56 | $this->assertSame("'Naughty \\' string'", $quoter->quoteValue("Naughty ' string"));
57 | $this->assertSame("'@þÿ€'", $quoter->quoteValue('@þÿ€'));
58 | // Injection patterns
59 | $this->assertSame("'\\' OR \\'\\'=\\''", $quoter->quoteValue("' OR ''='"));
60 | $this->assertSame("'1\\' or \\'1\\' = \\'1'", $quoter->quoteValue("1' or '1' = '1"));
61 | $this->assertSame("'1\\' or \\'1\\' = \\'1\\'))/*'", $quoter->quoteValue("1' or '1' = '1'))/*"));
62 | }
63 |
64 | /**
65 | * Test.
66 | *
67 | * @return void
68 | */
69 | public function testQuoteName(): void
70 | {
71 | $quoter = $this->getConnection()->getQuoter();
72 |
73 | $this->assertSame('``', $quoter->quoteName(''));
74 | $this->assertSame('*', $quoter->quoteName('*'));
75 |
76 | // Table
77 | $this->assertSame('`abc123`', $quoter->quoteName('abc123'));
78 | $this->assertSame('`user_roles`', $quoter->quoteName('user_roles '));
79 | $this->assertSame('`öäüÖÄÜß`', $quoter->quoteName('öäüÖÄÜß'));
80 | $this->assertSame('`table`.*', $quoter->quoteName('table.*'));
81 |
82 | // Table with alias
83 | $this->assertSame('`users` AS `u`', $quoter->quoteName(['u' => 'users']));
84 |
85 | // With database name
86 | $this->assertSame('`dbname`.`tablename`', $quoter->quoteName('dbname.tablename'));
87 | $this->assertSame('`dbname`.`tablename`.`field`', $quoter->quoteName('dbname.tablename.field'));
88 | // Alias.field AS thing
89 | $this->assertSame(
90 | '`dbname`.`tablename`.`field` AS `thing`',
91 | $quoter->quoteName(['thing' => 'dbname.tablename.field'])
92 | );
93 |
94 | $this->assertSame('`.`', $quoter->quoteName('.'));
95 | $this->assertSame('`?`', $quoter->quoteName('?'));
96 | $this->assertSame('`:`', $quoter->quoteName(':'));
97 | $this->assertSame('`,`', $quoter->quoteName(','));
98 | $this->assertSame("`',`", $quoter->quoteName("',"));
99 | $this->assertSame('````', $quoter->quoteName('`'));
100 | $this->assertSame('`%s`', $quoter->quoteName('%s'));
101 | $this->assertSame("`Naughty-'-string`", $quoter->quoteName("Naughty-'-string"));
102 | $this->assertSame('`@þÿ€`', $quoter->quoteName('@þÿ€'));
103 | }
104 |
105 | /**
106 | * Test.
107 | *
108 | * @return void
109 | */
110 | public function testQuoteArray(): void
111 | {
112 | $quoter = $this->getConnection()->getQuoter();
113 | $this->assertSame([], $quoter->quoteArray([]));
114 |
115 | $row = ['1', '2', '3', null];
116 | $this->assertSame(["'1'", "'2'", "'3'", 'NULL'], $quoter->quoteArray($row));
117 |
118 | $row = ['1', '2', '3', new RawExp('a.b')];
119 | $this->assertSame(["'1'", "'2'", "'3'", 'a.b'], $quoter->quoteArray($row));
120 | }
121 |
122 | /**
123 | * Test.
124 | *
125 | * @return void
126 | */
127 | public function testQuoteNames(): void
128 | {
129 | $quoter = $this->getConnection()->getQuoter();
130 | $this->assertSame([], $quoter->quoteNames([]));
131 |
132 | $row = ['a', 'a.b', 'a.b.c', new RawExp('a.z')];
133 | $this->assertSame(['`a`', '`a`.`b`', '`a`.`b`.`c`', 'a.z'], $quoter->quoteNames($row));
134 | }
135 |
136 | /**
137 | * Test.
138 | *
139 | * @return void
140 | */
141 | public function testQuoteByFields(): void
142 | {
143 | $quoter = $this->getConnection()->getQuoter();
144 | $this->assertSame([], $quoter->quoteByFields([]));
145 |
146 | $row = ['a', 'a.b', 'a.b.c', new RawExp('a.z')];
147 | $this->assertSame(['`a`', '`a`.`b`', '`a`.`b`.`c`', 'a.z'], $quoter->quoteByFields($row));
148 |
149 | $row = ['ÿ', "\0", "'", '"'];
150 | $this->assertSame(['`ÿ`', '``', "`'`", '`"`'], $quoter->quoteByFields($row));
151 | }
152 | }
153 |
--------------------------------------------------------------------------------
/tests/RawExpTest.php:
--------------------------------------------------------------------------------
1 | assertSame('123', $exp->getValue());
21 | }
22 |
23 | /**
24 | * Test.
25 | *
26 | * @return void
27 | */
28 | public function testToString(): void
29 | {
30 | $exp = new RawExp('abc');
31 | $this->assertSame('abc', $exp->__toString());
32 | }
33 |
34 | /**
35 | * Test.
36 | *
37 | * @return void
38 | */
39 | public function testColumnsRaw(): void
40 | {
41 | $select = $this->select()
42 | ->columns([
43 | new RawExp('COUNT(*) AS user_count'),
44 | 'status',
45 | ])
46 | ->from('payments')
47 | ->where('status', '<>', 1)
48 | ->groupBy('status')
49 | ->build();
50 | $this->assertSame('SELECT COUNT(*) AS user_count,`status` ' .
51 | "FROM `payments` WHERE `status` <> '1' GROUP BY `status`;", $select);
52 | }
53 |
54 | /**
55 | * Test.
56 | *
57 | * @return void
58 | */
59 | public function testColumnsRaw2(): void
60 | {
61 | $select = $this->select()
62 | ->columns([
63 | new RawExp('MAX(amount)'),
64 | new RawExp('MIN(amount)'),
65 | ])
66 | ->from('payments')
67 | ->build();
68 | $this->assertSame('SELECT MAX(amount),MIN(amount) FROM `payments`;', $select);
69 | }
70 | }
71 |
--------------------------------------------------------------------------------
/tests/SelectQueryTest.php:
--------------------------------------------------------------------------------
1 | createTestTable();
24 | }
25 |
26 | /**
27 | * Test create object.
28 | */
29 | public function testInstance(): void
30 | {
31 | $this->assertInstanceOf(SelectQuery::class, $this->select());
32 | }
33 |
34 | /**
35 | * Test.
36 | */
37 | public function testDistinct(): void
38 | {
39 | $select = $this->select()->distinct()->columns(['id'])->from('test');
40 | $this->assertInstanceOf(PDOStatement::class, $select->prepare());
41 | $this->assertSame('SELECT DISTINCT `id` FROM `test`;', $select->build());
42 |
43 | $select = $this->select()->distinctRow()->columns(['id'])->from('test');
44 | $this->assertInstanceOf(PDOStatement::class, $select->prepare());
45 | $this->assertSame('SELECT DISTINCTROW `id` FROM `test`;', $select->build());
46 | }
47 |
48 | /**
49 | * Test.
50 | */
51 | public function testStraightJoin(): void
52 | {
53 | $select = $this->select()->straightJoin()->from('users');
54 | $this->assertInstanceOf(PDOStatement::class, $select->prepare());
55 | $this->assertSame('SELECT STRAIGHT_JOIN * FROM `users`;', $select->build());
56 | }
57 |
58 | /**
59 | * Test.
60 | */
61 | public function testHighPriority(): void
62 | {
63 | $select = $this->select()->highPriority()->from('users');
64 | $this->assertInstanceOf(PDOStatement::class, $select->prepare());
65 | $this->assertSame('SELECT HIGH_PRIORITY * FROM `users`;', $select->build());
66 | }
67 |
68 | /**
69 | * Test.
70 | */
71 | public function testSmallResult(): void
72 | {
73 | $select = $this->select()->smallResult()->from('users');
74 | $this->assertInstanceOf(PDOStatement::class, $select->prepare());
75 | $this->assertSame('SELECT SQL_SMALL_RESULT * FROM `users`;', $select->build());
76 | }
77 |
78 | /**
79 | * Test.
80 | */
81 | public function testBigResult(): void
82 | {
83 | $select = $this->select()->bigResult()->from('users');
84 | $this->assertInstanceOf(PDOStatement::class, $select->prepare());
85 | $this->assertSame('SELECT SQL_BIG_RESULT * FROM `users`;', $select->build());
86 | }
87 |
88 | /**
89 | * Test.
90 | */
91 | public function testBufferResult(): void
92 | {
93 | $select = $this->select()->bufferResult()->from('users');
94 | $this->assertSame('SELECT SQL_BUFFER_RESULT * FROM `users`;', $select->build());
95 | }
96 |
97 | /**
98 | * Test.
99 | */
100 | public function testCalcFoundRows(): void
101 | {
102 | $select = $this->select()->calcFoundRows()->from('users');
103 | $this->assertSame('SELECT SQL_CALC_FOUND_ROWS * FROM `users`;', $select->build());
104 | }
105 |
106 | /**
107 | * Test.
108 | */
109 | public function testColumns(): void
110 | {
111 | $select = $this->select()->from('users');
112 | $this->assertSame('SELECT * FROM `users`;', $select->build());
113 |
114 | $select = $this->select()->columns(['id', 'username', ['firstName' => 'first_name']])->from('test');
115 | $this->assertSame('SELECT `id`,`username`,`first_name` AS `firstName` FROM `test`;', $select->build());
116 |
117 | $select = $this->select()->columns(['id', 'username', ['firstName' => 'first_name']])->from('test');
118 | $this->assertSame('SELECT `id`,`username`,`first_name` AS `firstName` FROM `test`;', $select->build());
119 |
120 | // queries without table
121 | $select = $this->select()->columns([new RawExp('ISNULL(1+1)')]);
122 | $this->assertSame('SELECT ISNULL(1+1);', $select->build());
123 |
124 | $select = $this->select()->columns([new RawExp('INTERVAL(23, 1, 15, 17, 30, 44, 200)')]);
125 | $this->assertSame('SELECT INTERVAL(23, 1, 15, 17, 30, 44, 200);', $select->build());
126 | }
127 |
128 | /**
129 | * Test.
130 | */
131 | public function testColumnsArray(): void
132 | {
133 | $query = $this->select()->from('test');
134 |
135 | $query->columns([
136 | 'id',
137 | 'username',
138 | 'firstName' => 'first_name',
139 | 'last_name' => 'test.last_name',
140 | 'email' => 'database.test.email',
141 | 'value' => $query->raw('CONCAT("1","2")'),
142 | ]);
143 |
144 | $this->assertSame('SELECT `id`,`username`,`first_name` AS `firstName`,`test`.`last_name` AS `last_name`,' .
145 | '`database`.`test`.`email` AS `email`,CONCAT("1","2") AS `value` FROM `test`;', $query->build());
146 | }
147 |
148 | /**
149 | * Test.
150 | */
151 | public function testMultipleColumns(): void
152 | {
153 | $select = $this->select()->columns(['id', 'username', ['firstName' => 'first_name']])->from('test');
154 | $select = $select->columns([['username2' => 'username'], 'id2', 'table.fieldname2']);
155 |
156 | $sql = $select->build();
157 | $this->assertSame(
158 | 'SELECT `id`,`username`,`first_name` AS `firstName`,`username` AS ' .
159 | '`username2`,`id2`,`table`.`fieldname2` FROM `test`;',
160 | $sql
161 | );
162 | }
163 |
164 | /**
165 | * Test.
166 | */
167 | public function testSubselect(): void
168 | {
169 | // Raw
170 | $select = $this->select()
171 | ->columns(['id', new RawExp('(SELECT MAX(payments.amount) FROM payments) AS max_amount')])
172 | ->from('test');
173 | $this->assertSame(
174 | 'SELECT `id`,(SELECT MAX(payments.amount) FROM payments) AS max_amount FROM `test`;',
175 | $select->build()
176 | );
177 |
178 | // With a sub query object
179 | $select = $this->select()
180 | ->columns([
181 | 'id',
182 | function (SelectQuery $subSelect) {
183 | $subSelect->columns([new RawExp('MAX(payments.amount)')])
184 | ->from('payments')
185 | ->alias('max_amount'); // AS max_amount
186 | },
187 | ])
188 | ->from('test');
189 |
190 | $this->assertSame(
191 | 'SELECT `id`,(SELECT MAX(payments.amount) FROM `payments`) AS `max_amount` FROM `test`;',
192 | $select->build()
193 | );
194 | }
195 |
196 | /**
197 | * Test.
198 | */
199 | public function testUnion(): void
200 | {
201 | $select = $this->select()->columns(['id'])->from('table1');
202 | $select2 = $this->select()->columns(['id'])->from('table2');
203 | $select->union($select2);
204 | $this->assertSame('SELECT `id` FROM `table1` UNION SELECT `id` FROM `table2`;', $select->build());
205 |
206 | $select = $this->select()->columns(['id'])->from('table1');
207 | $select2 = $this->select()->columns(['id'])->from('table2');
208 | $select->unionAll($select2);
209 | $this->assertSame('SELECT `id` FROM `table1` UNION ALL SELECT `id` FROM `table2`;', $select->build());
210 |
211 | $select = $this->select()->columns(['id'])->from('table1');
212 | $select2 = $this->select()->columns(['id'])->from('table2');
213 | $select->unionDistinct($select2);
214 | $this->assertSame('SELECT `id` FROM `table1` UNION DISTINCT SELECT `id` FROM `table2`;', $select->build());
215 | }
216 |
217 | /**
218 | * Test.
219 | */
220 | public function testFrom(): void
221 | {
222 | $select = $this->select()->columns(['id'])->from('test');
223 | $this->assertSame('SELECT `id` FROM `test`;', $select->build());
224 |
225 | $select = $this->select()->columns(['id'])->from(['t' => 'test']);
226 | $this->assertSame('SELECT `id` FROM `test` AS `t`;', $select->build());
227 |
228 | $select = $this->select()->columns(['id'])->from(['t' => 'dbname.test']);
229 | $this->assertSame('SELECT `id` FROM `dbname`.`test` AS `t`;', $select->build());
230 | }
231 |
232 | /**
233 | * Test.
234 | */
235 | public function testWhere(): void
236 | {
237 | $select = $this->select()->columns(['id'])->from('test')->where('id', '=', 1);
238 | $this->assertSame("SELECT `id` FROM `test` WHERE `id` = '1';", $select->build());
239 |
240 | $select = $this->select()->columns(['id'])->from('test')->where('id', '>=', 3);
241 | $this->assertSame("SELECT `id` FROM `test` WHERE `id` >= '3';", $select->build());
242 |
243 | $select = $this->select()->columns(['id'])->from('test')->where('id', '>', 4);
244 | $this->assertSame("SELECT `id` FROM `test` WHERE `id` > '4';", $select->build());
245 |
246 | $select = $this->select()->columns(['id'])->from('test')->where('id', '<', 5);
247 | $this->assertSame("SELECT `id` FROM `test` WHERE `id` < '5';", $select->build());
248 |
249 | $select = $this->select()->columns(['id'])->from('test')->where('id', '<=', 6);
250 | $this->assertSame("SELECT `id` FROM `test` WHERE `id` <= '6';", $select->build());
251 |
252 | $select = $this->select()->columns(['id'])->from('test')->where('id', '<>', 7);
253 | $this->assertSame("SELECT `id` FROM `test` WHERE `id` <> '7';", $select->build());
254 |
255 | $select = $this->select()->columns(['id'])->from('test')->where('id', '!=', 8);
256 | $this->assertSame("SELECT `id` FROM `test` WHERE `id` != '8';", $select->build());
257 |
258 | $select = $this->select()->columns(['id'])->from('test')->where('id', '<>', null);
259 | $this->assertSame('SELECT `id` FROM `test` WHERE `id` IS NOT NULL;', $select->build());
260 |
261 | $select = $this->select()->columns(['id'])->from('test')->where('id', '!=', null);
262 | $this->assertSame('SELECT `id` FROM `test` WHERE `id` IS NOT NULL;', $select->build());
263 |
264 | $select = $this->select()->columns(['id'])->from('test')->where('id', '=', null);
265 | $this->assertSame('SELECT `id` FROM `test` WHERE `id` IS NULL;', $select->build());
266 |
267 | $select = $this->select()->columns(['id'])->from('test')->where('id', 'is', null);
268 | $this->assertSame('SELECT `id` FROM `test` WHERE `id` IS NULL;', $select->build());
269 |
270 | $select = $this->select()->columns(['id'])->from('test')->where('id', 'is not', null);
271 | $this->assertSame('SELECT `id` FROM `test` WHERE `id` IS NOT NULL;', $select->build());
272 |
273 | $select = $this->select()->columns(['*'])->from('users')->where('username', '=', "hello' or 1=1;--");
274 | $this->assertSame("SELECT * FROM `users` WHERE `username` = 'hello\' or 1=1;--';", $select->build());
275 | }
276 |
277 | /**
278 | * Test.
279 | */
280 | public function testWhereIn(): void
281 | {
282 | $select = $this->select()->columns(['id'])->from('test')->where('id', 'in', [1, 'a', "'b", null]);
283 | $this->assertSame("SELECT `id` FROM `test` WHERE `id` IN ('1', 'a', '\'b', NULL);", $select->build());
284 |
285 | $select = $this->select()->columns(['id'])->from('test')->where('id', 'not in', [2, 'a', "'b", null]);
286 | $this->assertSame("SELECT `id` FROM `test` WHERE `id` NOT IN ('2', 'a', '\'b', NULL);", $select->build());
287 | }
288 |
289 | /**
290 | * Test.
291 | */
292 | public function testWhereFunction(): void
293 | {
294 | $select = $this->select()->columns(['id'])->from('test')->where('id', 'greatest', [1, '2', "'b", null]);
295 | $this->assertSame("SELECT `id` FROM `test` WHERE `id` = GREATEST ('1', '2', '\'b', NULL);", $select->build());
296 |
297 | $select = $this->select()->columns(['id'])->from('test')->where('id', 'interval', [1, 2, 3]);
298 | $this->assertSame("SELECT `id` FROM `test` WHERE `id` = INTERVAL ('1', '2', '3');", $select->build());
299 |
300 | $select = $this->select()->columns(['id'])->from('test')->where('id', 'strcmp', ['text', "text'2"]);
301 | $this->assertSame("SELECT `id` FROM `test` WHERE `id` = STRCMP ('text', 'text\'2');", $select->build());
302 | }
303 |
304 | /**
305 | * Test.
306 | */
307 | public function testWhereBetween(): void
308 | {
309 | $select = $this->select()->columns(['id'])->from('test')->where('id', 'between', [1, 100]);
310 | $this->assertSame("SELECT `id` FROM `test` WHERE `id` BETWEEN '1' AND '100';", $select->build());
311 | }
312 |
313 | /**
314 | * Test Simple pattern matching.
315 | */
316 | public function testWhereLike(): void
317 | {
318 | $select = $this->select()->columns(['id'])->from('test')->where('first_name', 'like', '%max%');
319 | $this->assertSame("SELECT `id` FROM `test` WHERE `first_name` LIKE '%max%';", $select->build());
320 |
321 | $select = $this->select()->columns(['id'])->from('test')->where('first_name', 'like', "%a'b%");
322 | $this->assertSame("SELECT `id` FROM `test` WHERE `first_name` LIKE '%a\'b%';", $select->build());
323 |
324 | $select = $this->select()->columns(['id'])->from('test')->where('first_name', 'not like', "%a'1%");
325 | $this->assertSame("SELECT `id` FROM `test` WHERE `first_name` NOT LIKE '%a\'1%';", $select->build());
326 | }
327 |
328 | /**
329 | * Test Simple pattern matching.
330 | */
331 | public function testWhereRegexp(): void
332 | {
333 | $select = $this->select()->from('users')->where('username', Operator::REGEXP, '^[a-d]');
334 | $this->assertSame("SELECT * FROM `users` WHERE `username` REGEXP '^[a-d]';", $select->build());
335 |
336 | $select = $this->select()->from('users')->where('username', Operator::REGEXP, 'new\\*.\\*line');
337 | $this->assertSame("SELECT * FROM `users` WHERE `username` REGEXP 'new\\\\*.\\\\*line';", $select->build());
338 | }
339 |
340 | /**
341 | * Test.
342 | */
343 | public function testWhereRawExp(): void
344 | {
345 | $select = $this->select()->columns(['id'])->from('test')->where(new RawExp("STRCMP('text', 'text2')"));
346 | $this->assertSame("SELECT `id` FROM `test` WHERE STRCMP('text', 'text2');", $select->build());
347 |
348 | $select = $this->select()->columns(['id'])->from('test')->where(new RawExp('ISNULL(1+1)'));
349 | $this->assertSame('SELECT `id` FROM `test` WHERE ISNULL(1+1);', $select->build());
350 | }
351 |
352 | /**
353 | * Test.
354 | */
355 | public function testWhereRaw(): void
356 | {
357 | $select = $this->select()
358 | ->columns(['id'])
359 | ->from('test')
360 | ->whereRaw("STRCMP('text', 'text2')");
361 | $this->assertSame("SELECT `id` FROM `test` WHERE STRCMP('text', 'text2');", $select->build());
362 | }
363 |
364 | /**
365 | * Test.
366 | */
367 | public function testOrWhereRaw(): void
368 | {
369 | $select = $this->select()
370 | ->columns(['id'])
371 | ->from('test')
372 | ->whereRaw("STRCMP('text', 'text2')")
373 | ->orWhereRaw('1=1');
374 | $this->assertSame("SELECT `id` FROM `test` WHERE STRCMP('text', 'text2') OR 1=1;", $select->build());
375 | }
376 |
377 | /**
378 | * Test.
379 | */
380 | public function testOrWhereRawClosure(): void
381 | {
382 | $select = $this->select()
383 | ->columns(['id'])
384 | ->from('test')
385 | ->where(function (SelectQuery $query) {
386 | $query->where('field2', '=', 'value2');
387 | });
388 |
389 | $sql = $select->build();
390 | $this->assertSame("SELECT `id` FROM `test` WHERE ( `field2` = 'value2' );", $sql);
391 | }
392 |
393 | /**
394 | * Test.
395 | */
396 | public function testOrWhereRawClosure2(): void
397 | {
398 | $select = $this->select()
399 | ->columns(['id'])
400 | ->from('test')
401 | ->where(function (SelectQuery $query) {
402 | $query->where('field2', '=', 'value2')
403 | ->whereRaw('0=0')
404 | ->orWhereRaw('1=1');
405 | });
406 |
407 | $sql = $select->build();
408 | $this->assertSame("SELECT `id` FROM `test` WHERE ( `field2` = 'value2' AND 0=0 OR 1=1 );", $sql);
409 | }
410 |
411 | /**
412 | * Test.
413 | */
414 | public function testOrWhereRawClosure3(): void
415 | {
416 | $select = $this->select()
417 | ->columns(['id'])
418 | ->from('test')
419 | ->where('field', '=', 'value')
420 | ->where(function (SelectQuery $query) {
421 | $query->whereRaw('0=0')
422 | ->orWhereRaw('1=1');
423 | });
424 |
425 | $sql = $select->build();
426 | $this->assertSame("SELECT `id` FROM `test` WHERE `field` = 'value' AND ( 0=0 OR 1=1 );", $sql);
427 | }
428 |
429 | /**
430 | * Test.
431 | */
432 | public function testWhereColumn(): void
433 | {
434 | $select = $this->select()->from('users')->whereColumn('first_name', '=', 'last_name');
435 | $this->assertSame('SELECT * FROM `users` WHERE `first_name` = `last_name`;', $select->build());
436 |
437 | $select = $select->orWhereColumn('votes', '>=', 'vote_max');
438 | $this->assertSame(
439 | 'SELECT * FROM `users` WHERE `first_name` = `last_name` OR `votes` >= `vote_max`;',
440 | $select->build()
441 | );
442 |
443 | $select = $this->select()->from('users')->whereColumn('users.email', '=', 'table2.email');
444 | $this->assertSame('SELECT * FROM `users` WHERE `users`.`email` = `table2`.`email`;', $select->build());
445 |
446 | $select = $this->select()->from('users')
447 | ->whereColumn('first_name', '=', 'last_name')
448 | ->whereColumn('updated_at', '=', 'created_at');
449 | $this->assertSame(
450 | 'SELECT * FROM `users` WHERE `first_name` = `last_name` AND `updated_at` = `created_at`;',
451 | $select->build()
452 | );
453 | }
454 |
455 | /**
456 | * Test.
457 | */
458 | public function testWhereClosure(): void
459 | {
460 | $select = $this->select()
461 | ->distinct()
462 | ->columns(['id', 'username'])
463 | ->from(['u' => 'users'])
464 | ->join('customers c', 'c.created_by', '=', 'u.id')
465 | ->leftJoin('articles a', 'a.created_by', '=', 'u.id')
466 | ->where('u.id', '>=', 1)
467 | ->where('u.deleted', '=', 0)
468 | ->orWhere('u.username', 'like', "%a'a%")
469 | ->orWhere('u.username', 'not like', "%a'b%")
470 | ->orWhere('u.id', 'in', [1, 2, 3])
471 | ->orWhere('u.id', 'not in', [4, 5, null])
472 | ->orWhere('u.id', '=', null)
473 | ->orWhere('u.id', '!=', null)
474 | ->where(function (SelectQuery $query) {
475 | $query->where('t2.field', '=', '1');
476 | $query->where('t2.field2', '>', '1');
477 | })
478 | ->orWhere(function (SelectQuery $query) {
479 | $query->where('t.a', '<>', '2');
480 | $query->where('t.b', '=', null);
481 | $query->where('t.c', '>', '5');
482 | $query->orWhere(function (SelectQuery $query) {
483 | $query->where(new RawExp('a.id = b.id'));
484 | $query->orWhere(new RawExp('c.id = u.id'));
485 | });
486 | })
487 | ->where('u.id', '>=', 0)
488 | ->orWhere('u.id', 'between', [100, 200])
489 | ->groupBy('id', 'username ASC')
490 | ->having('u.username', '=', '1')
491 | ->having('u.username', '=', '2')
492 | ->having(function (SelectQuery $query) {
493 | $query->having('x', '<>', '2');
494 | $query->having('y', '=', null);
495 | $query->having('z', '<>', '5');
496 | $query->orHaving(function (SelectQuery $query) {
497 | $query->having(new RawExp('a.id = b.id'));
498 | $query->orHaving(new RawExp('c.id = u.id'));
499 | });
500 | })
501 | ->groupBy('id', 'username', new RawExp('`role`'))
502 | ->orderBy('id ASC', 'username DESC', new RawExp('`role` ASC'))
503 | ->limit(10)
504 | ->offset(5);
505 |
506 | $sql = $select->build();
507 |
508 | $expected = 'd1de1a753a1a513e4e5b203ebfa7b8f75d7f2eec';
509 | $actual = sha1($sql);
510 |
511 | if ($expected !== $actual) {
512 | echo "\nSQL: $sql\n";
513 | file_put_contents(__DIR__ . '/debug.sql', $sql);
514 | }
515 |
516 | $this->assertSame($expected, $actual);
517 | }
518 |
519 | /**
520 | * Test.
521 | */
522 | public function testHavingRaw(): void
523 | {
524 | $query = $this->select();
525 | $query->columns(['state_id', $query->func()->count('*')]);
526 | $query->from('table');
527 | $query->groupBy('state_id', 'locality');
528 | $query->havingRaw('COUNT(*) > 1');
529 |
530 | $this->assertSame(
531 | 'SELECT `state_id`,COUNT(*) FROM `table` GROUP BY `state_id`, `locality` HAVING COUNT(*) > 1;',
532 | $query->build()
533 | );
534 | }
535 |
536 | /**
537 | * Test.
538 | */
539 | public function testOrHavingRaw(): void
540 | {
541 | $query = $this->select();
542 | $query->columns(['state_id', $query->func()->count('*')]);
543 | $query->from('table');
544 | $query->groupBy('state_id', 'locality');
545 | $query->havingRaw('COUNT(*) > 1');
546 | $query->orHavingRaw('brand LIKE %acme%');
547 |
548 | $this->assertSame(
549 | 'SELECT `state_id`,COUNT(*) FROM `table` GROUP BY `state_id`, `locality` ' .
550 | 'HAVING COUNT(*) > 1 OR brand LIKE %acme%;',
551 | $query->build()
552 | );
553 | }
554 |
555 | /**
556 | * Test.
557 | */
558 | public function testJoin(): void
559 | {
560 | $select = $this->select()
561 | ->columns(['id'])
562 | ->from(['t' => 'test'])
563 | ->join(['u' => 'users'], 'u.id', '=', 'test.user_id');
564 |
565 | $this->assertSame(
566 | 'SELECT `id` FROM `test` AS `t` INNER JOIN `users` AS `u` ON `u`.`id` = `test`.`user_id`;',
567 | $select->build()
568 | );
569 |
570 | $select->innerJoin(['t2' => 'table2'], 't2.id', '=', 'test.user_id');
571 | $expected = 'SELECT `id` FROM `test` AS `t` INNER JOIN `users` AS `u` ON `u`.`id` = `test`.`user_id` ' .
572 | 'INNER JOIN `table2` AS `t2` ON `t2`.`id` = `test`.`user_id`;';
573 | $this->assertSame($expected, $select->build());
574 | }
575 |
576 | /**
577 | * Test.
578 | */
579 | public function testJoinRaw(): void
580 | {
581 | $select = $this->select()
582 | ->columns(['id'])
583 | ->from('test')
584 | ->joinRaw(['u' => 'users'], 't2.a=t1.a AND t3.b=t1.b AND t4.c=t1.c OR t2.b IS NULL');
585 |
586 | $this->assertSame(
587 | 'SELECT `id` FROM `test` INNER JOIN `users` AS `u` ON (t2.a=t1.a AND t3.b=t1.b ' .
588 | 'AND t4.c=t1.c OR t2.b IS NULL);',
589 | $select->build()
590 | );
591 | }
592 |
593 | /**
594 | * Test.
595 | */
596 | public function testLeftJoinRaw(): void
597 | {
598 | $select = $this->select()
599 | ->columns(['id'])
600 | ->from('test')
601 | ->leftJoinRaw(['u' => 'users'], 't2.a=t1.a AND t3.b=t1.b AND t4.c=t1.c OR t2.b IS NULL');
602 |
603 | $this->assertSame(
604 | 'SELECT `id` FROM `test` LEFT JOIN `users` AS `u` ' .
605 | 'ON (t2.a=t1.a AND t3.b=t1.b AND t4.c=t1.c OR t2.b IS NULL);',
606 | $select->build()
607 | );
608 | }
609 |
610 | /**
611 | * Test.
612 | */
613 | public function testLeftJoin(): void
614 | {
615 | $select = $this->select()
616 | ->columns(['id'])
617 | ->from('test')
618 | ->leftJoin(['u' => 'users'], 'u.id', '=', 'test.user_id');
619 |
620 | $this->assertSame(
621 | 'SELECT `id` FROM `test` LEFT JOIN `users` AS `u` ON `u`.`id` = `test`.`user_id`;',
622 | $select->build()
623 | );
624 |
625 | $select->leftJoin(['t2' => 'table2'], 't2.id', '=', 'test.user_id');
626 | $expected = 'SELECT `id` FROM `test` ' .
627 | 'LEFT JOIN `users` AS `u` ON `u`.`id` = `test`.`user_id` ' .
628 | 'LEFT JOIN `table2` AS `t2` ON `t2`.`id` = `test`.`user_id`;';
629 | $this->assertSame($expected, $select->build());
630 | }
631 |
632 | /**
633 | * Test.
634 | */
635 | public function testLimit(): void
636 | {
637 | $select = $this->select()->columns(['id'])->from('test')->limit(10);
638 | $this->assertSame('SELECT `id` FROM `test` LIMIT 10;', $select->build());
639 | }
640 |
641 | /**
642 | * Test.
643 | *
644 | * @return void
645 | */
646 | public function testRaw(): void
647 | {
648 | $query = $this->getConnection()->select();
649 |
650 | $this->assertEquals('value', $query->raw('value')->getValue());
651 |
652 | $query = $this->getConnection()->select();
653 | $query->columns([$query->raw('count(*) AS user_count'), 'status']);
654 | $query->from('payments');
655 |
656 | $this->assertEquals('SELECT count(*) AS user_count,`status` FROM `payments`;', $query->build());
657 | }
658 | }
659 |
--------------------------------------------------------------------------------
/tests/UpdateQueryTest.php:
--------------------------------------------------------------------------------
1 | createTestTable();
22 | }
23 |
24 | /**
25 | * Test create object.
26 | *
27 | * @return void
28 | */
29 | public function testInstance(): void
30 | {
31 | $this->assertInstanceOf(UpdateQuery::class, $this->update());
32 | }
33 |
34 | /**
35 | * Create query.
36 | *
37 | * @return UpdateQuery The query
38 | */
39 | protected function update(): UpdateQuery
40 | {
41 | return new UpdateQuery($this->getConnection());
42 | }
43 |
44 | /**
45 | * Test.
46 | */
47 | public function testFrom(): void
48 | {
49 | $update = $this->update()->table('test')->set(['keyname' => 'admin'])->where('id', '=', '1');
50 | $this->assertSame("UPDATE `test` SET `keyname`='admin' WHERE `id` = '1';", $update->build());
51 | $this->assertTrue($update->execute());
52 | }
53 |
54 | /**
55 | * Test.
56 | */
57 | public function testLowPriority(): void
58 | {
59 | $update = $this->update()->lowPriority()->table('test')->set(['username' => 'admin']);
60 | $this->assertSame("UPDATE LOW_PRIORITY `test` SET `username`='admin';", $update->build());
61 | }
62 |
63 | /**
64 | * Test.
65 | */
66 | public function testIgnore(): void
67 | {
68 | $update = $this->update()->ignore()->table('test')->set(['username' => 'admin']);
69 | $this->assertSame("UPDATE IGNORE `test` SET `username`='admin';", $update->build());
70 |
71 | $update = $this->update()->lowPriority()->ignore()->table('test')->set(['username' => 'admin']);
72 | $this->assertSame("UPDATE LOW_PRIORITY IGNORE `test` SET `username`='admin';", $update->build());
73 | }
74 |
75 | /**
76 | * Test.
77 | */
78 | public function testOrderBy(): void
79 | {
80 | $update = $this->update()->table('users')->set(['username' => 'admin'])->orderBy('id');
81 | $this->assertSame("UPDATE `users` SET `username`='admin' ORDER BY `id`;", $update->build());
82 |
83 | $update = $this->update()->table('users')->set(['username' => 'admin'])->orderBy('id DESC');
84 | $this->assertSame("UPDATE `users` SET `username`='admin' ORDER BY `id` DESC;", $update->build());
85 |
86 | $update = $this->update()->table('users')->set(['username' => 'admin'])->orderBy('users.id ASC');
87 | $this->assertSame("UPDATE `users` SET `username`='admin' ORDER BY `users`.`id` ASC;", $update->build());
88 |
89 | $update = $this->update()->table('users')->set(['username' => 'admin'])->orderBy('db.users.id ASC');
90 | $this->assertSame("UPDATE `users` SET `username`='admin' ORDER BY `db`.`users`.`id` ASC;", $update->build());
91 | }
92 |
93 | /**
94 | * Test.
95 | */
96 | public function testLimit(): void
97 | {
98 | $update = $this->update()->table('test')->set(['username' => 'admin'])->limit(10);
99 | $this->assertSame("UPDATE `test` SET `username`='admin' LIMIT 10;", $update->build());
100 | }
101 |
102 | /**
103 | * Test.
104 | */
105 | public function testWhere(): void
106 | {
107 | $update = $this->update()->table('test')->set(['username' => 'admin'])
108 | ->where('test.id', '=', 1)
109 | ->orWhere('db.test.id', '>', 2);
110 | $this->assertSame(
111 | "UPDATE `test` SET `username`='admin' WHERE `test`.`id` = '1' OR `db`.`test`.`id` > '2';",
112 | $update->build()
113 | );
114 | }
115 |
116 | /**
117 | * Test.
118 | */
119 | public function testIncrementDecrement(): void
120 | {
121 | $update = $this->update()->table('users')->increment('voted');
122 | $this->assertSame("UPDATE `users` SET `voted`=`voted`+'1';", $update->build());
123 |
124 | $update = $this->update()->table('users')->increment('voted', 1)
125 | ->where('test.id', '=', 1)
126 | ->orWhere('db.test.id', '>', 2);
127 | $this->assertSame(
128 | "UPDATE `users` SET `voted`=`voted`+'1' WHERE `test`.`id` = '1' OR `db`.`test`.`id` > '2';",
129 | $update->build()
130 | );
131 |
132 | $update = $this->update()->table('users')->decrement('voted', 10)
133 | ->where('test.id', '=', 1)
134 | ->orWhere('db.test.id', '>', 2);
135 | $this->assertSame(
136 | "UPDATE `users` SET `voted`=`voted`-'10' WHERE `test`.`id` = '1' OR `db`.`test`.`id` > '2';",
137 | $update->build()
138 | );
139 |
140 | $update = $this->update()->table('users')->set(['votes' => new RawExp('votes+1')])->where('id', '=', '1');
141 | $this->assertSame("UPDATE `users` SET `votes`=votes+1 WHERE `id` = '1';", $update->build());
142 | }
143 | }
144 |
--------------------------------------------------------------------------------