- `ORDER BY` clauses support qualified fields - Restrict supported PHP versions; this will prevent inadvertent upgrades to the upcoming 8.4-compliant version Reviewed-on: #6
		
			
				
	
	
		
			324 lines
		
	
	
		
			14 KiB
		
	
	
	
		
			PHP
		
	
	
	
	
	
			
		
		
	
	
			324 lines
		
	
	
		
			14 KiB
		
	
	
	
		
			PHP
		
	
	
	
	
	
<?php
 | 
						|
/**
 | 
						|
 * @author Daniel J. Summers <daniel@bitbadger.solutions>
 | 
						|
 * @license MIT
 | 
						|
 */
 | 
						|
 | 
						|
declare(strict_types=1);
 | 
						|
 | 
						|
namespace Test\Unit;
 | 
						|
 | 
						|
use BitBadger\PDODocument\{AutoId, Configuration, DocumentException, Field, FieldMatch, Mode, Query};
 | 
						|
use PHPUnit\Framework\Attributes\TestDox;
 | 
						|
use PHPUnit\Framework\TestCase;
 | 
						|
 | 
						|
/**
 | 
						|
 * Unit tests for the Query class
 | 
						|
 */
 | 
						|
#[TestDox('Query (Unit tests)')]
 | 
						|
class QueryTest extends TestCase
 | 
						|
{
 | 
						|
    protected function setUp(): void
 | 
						|
    {
 | 
						|
        Configuration::overrideMode(Mode::SQLite);
 | 
						|
    }
 | 
						|
 | 
						|
    protected function tearDown(): void
 | 
						|
    {
 | 
						|
        Configuration::overrideMode(null);
 | 
						|
    }
 | 
						|
 | 
						|
    #[TestDox('selectFromTable() succeeds')]
 | 
						|
    public function testSelectFromTableSucceeds(): void
 | 
						|
    {
 | 
						|
        $this->assertEquals('SELECT data FROM testing', Query::selectFromTable('testing'),
 | 
						|
            'Query not constructed correctly');
 | 
						|
    }
 | 
						|
 | 
						|
    #[TestDox('whereByFields() succeeds for single field')]
 | 
						|
    public function testWhereByFieldsSucceedsForSingleField(): void
 | 
						|
    {
 | 
						|
        $this->assertEquals("data->>'test_field' <= :it",
 | 
						|
            Query::whereByFields([Field::lessOrEqual('test_field', '', ':it')]),
 | 
						|
            'WHERE fragment not constructed correctly');
 | 
						|
    }
 | 
						|
 | 
						|
    #[TestDox('whereByFields() succeeds for multiple fields All')]
 | 
						|
    public function testWhereByFieldsSucceedsForMultipleFieldsAll(): void
 | 
						|
    {
 | 
						|
        $this->assertEquals("data->>'test_field' <= :it AND data->>'other_field' = :other",
 | 
						|
            Query::whereByFields(
 | 
						|
                [Field::lessOrEqual('test_field', '', ':it'), Field::equal('other_field', '', ':other')]),
 | 
						|
            'WHERE fragment not constructed correctly');
 | 
						|
    }
 | 
						|
 | 
						|
    #[TestDox('whereByFields() succeeds for multiple fields Any')]
 | 
						|
    public function testWhereByFieldsSucceedsForMultipleFieldsAny(): void
 | 
						|
    {
 | 
						|
        $this->assertEquals("data->>'test_field' <= :it OR data->>'other_field' = :other",
 | 
						|
            Query::whereByFields(
 | 
						|
                [Field::lessOrEqual('test_field', '', ':it'), Field::equal('other_field', '', ':other')],
 | 
						|
                FieldMatch::Any),
 | 
						|
            'WHERE fragment not constructed correctly');
 | 
						|
    }
 | 
						|
 | 
						|
    #[TestDox('whereById() succeeds with default parameter')]
 | 
						|
    public function testWhereByIdSucceedsWithDefaultParameter(): void
 | 
						|
    {
 | 
						|
        $this->assertEquals("data->>'id' = :id", Query::whereById(), 'WHERE fragment not constructed correctly');
 | 
						|
    }
 | 
						|
 | 
						|
    #[TestDox('whereById() succeeds with specific parameter')]
 | 
						|
    public function testWhereByIdSucceedsWithSpecificParameter(): void
 | 
						|
    {
 | 
						|
        $this->assertEquals("data->>'id' = :di", Query::whereById(':di'), 'WHERE fragment not constructed correctly');
 | 
						|
    }
 | 
						|
 | 
						|
    #[TestDox('whereDataContains() succeeds with default parameter')]
 | 
						|
    public function testWhereDataContainsSucceedsWithDefaultParameter(): void
 | 
						|
    {
 | 
						|
        Configuration::overrideMode(Mode::PgSQL);
 | 
						|
        $this->assertEquals('data @> :criteria', Query::whereDataContains(),
 | 
						|
            'WHERE fragment not constructed correctly');
 | 
						|
    }
 | 
						|
 | 
						|
    #[TestDox('whereDataContains() succeeds with specific parameter')]
 | 
						|
    public function testWhereDataContainsSucceedsWithSpecifiedParameter(): void
 | 
						|
    {
 | 
						|
        Configuration::overrideMode(Mode::PgSQL);
 | 
						|
        $this->assertEquals('data @> :it', Query::whereDataContains(':it'), 'WHERE fragment not constructed correctly');
 | 
						|
    }
 | 
						|
 | 
						|
    #[TestDox('whereDataContains() fails if not PostgreSQL')]
 | 
						|
    public function testWhereDataContainsFailsIfNotPostgreSQL(): void
 | 
						|
    {
 | 
						|
        Configuration::overrideMode(null);
 | 
						|
        $this->expectException(DocumentException::class);
 | 
						|
        Query::whereDataContains();
 | 
						|
    }
 | 
						|
 | 
						|
    #[TestDox('whereJsonPathMatches() succeeds with default parameter')]
 | 
						|
    public function testWhereJsonPathMatchesSucceedsWithDefaultParameter(): void
 | 
						|
    {
 | 
						|
        Configuration::overrideMode(Mode::PgSQL);
 | 
						|
        $this->assertEquals('jsonb_path_exists(data, :path::jsonpath)', Query::whereJsonPathMatches(),
 | 
						|
            'WHERE fragment not constructed correctly');
 | 
						|
    }
 | 
						|
 | 
						|
    #[TestDox('whereJsonPathMatches() succeeds with specified parameter')]
 | 
						|
    public function testWhereJsonPathMatchesSucceedsWithSpecifiedParameter(): void
 | 
						|
    {
 | 
						|
        Configuration::overrideMode(Mode::PgSQL);
 | 
						|
        $this->assertEquals('jsonb_path_exists(data, :road::jsonpath)', Query::whereJsonPathMatches(':road'),
 | 
						|
            'WHERE fragment not constructed correctly');
 | 
						|
    }
 | 
						|
 | 
						|
    #[TestDox('whereJsonPathMatches() fails if not PostgreSQL')]
 | 
						|
    public function testWhereJsonPathMatchesFailsIfNotPostgreSQL(): void
 | 
						|
    {
 | 
						|
        Configuration::overrideMode(null);
 | 
						|
        $this->expectException(DocumentException::class);
 | 
						|
        Query::whereJsonPathMatches();
 | 
						|
    }
 | 
						|
 | 
						|
    #[TestDox('insert() succeeds with no auto-ID for PostgreSQL')]
 | 
						|
    public function testInsertSucceedsWithNoAutoIdForPostgreSQL(): void
 | 
						|
    {
 | 
						|
        Configuration::overrideMode(Mode::PgSQL);
 | 
						|
        $this->assertEquals('INSERT INTO test_tbl VALUES (:data)', Query::insert('test_tbl'),
 | 
						|
            'INSERT statement not constructed correctly');
 | 
						|
    }
 | 
						|
 | 
						|
    #[TestDox('insert() succeeds with no auto-ID for SQLite')]
 | 
						|
    public function testInsertSucceedsWithNoAutoIdForSQLite(): void
 | 
						|
    {
 | 
						|
        $this->assertEquals('INSERT INTO test_tbl VALUES (:data)', Query::insert('test_tbl'),
 | 
						|
            'INSERT statement not constructed correctly');
 | 
						|
    }
 | 
						|
 | 
						|
    #[TestDox('insert() succeeds with auto numeric ID for PostgreSQL')]
 | 
						|
    public function testInsertSucceedsWithAutoNumericIdForPostgreSQL(): void
 | 
						|
    {
 | 
						|
        Configuration::overrideMode(Mode::PgSQL);
 | 
						|
        $this->assertEquals(
 | 
						|
            "INSERT INTO test_tbl VALUES (:data::jsonb || ('{\"id\":' "
 | 
						|
                . "|| (SELECT COALESCE(MAX((data->>'id')::numeric), 0) + 1 FROM test_tbl) || '}')::jsonb)",
 | 
						|
            Query::insert('test_tbl', AutoId::Number), 'INSERT statement not constructed correctly');
 | 
						|
    }
 | 
						|
 | 
						|
    #[TestDox('insert() succeeds with auto numeric ID for SQLite')]
 | 
						|
    public function testInsertSucceedsWithAutoNumericIdForSQLite(): void
 | 
						|
    {
 | 
						|
        $this->assertEquals(
 | 
						|
            "INSERT INTO test_tbl VALUES (json_set(:data, '$.id', "
 | 
						|
                . "(SELECT coalesce(max(data->>'id'), 0) + 1 FROM test_tbl)))",
 | 
						|
            Query::insert('test_tbl', AutoId::Number), 'INSERT statement not constructed correctly');
 | 
						|
    }
 | 
						|
 | 
						|
    #[TestDox('insert() succeeds with auto UUID for PostgreSQL')]
 | 
						|
    public function testInsertSucceedsWithAutoUuidForPostgreSQL(): void
 | 
						|
    {
 | 
						|
        Configuration::overrideMode(Mode::PgSQL);
 | 
						|
        $query = Query::insert('test_tbl', AutoId::UUID);
 | 
						|
        $this->assertStringStartsWith("INSERT INTO test_tbl VALUES (:data::jsonb || '{\"id\":\"", $query,
 | 
						|
            'INSERT statement not constructed correctly');
 | 
						|
        $this->assertStringEndsWith("\"}')", $query, 'INSERT statement not constructed correctly');
 | 
						|
    }
 | 
						|
 | 
						|
    #[TestDox('insert() succeeds with auto UUID for SQLite')]
 | 
						|
    public function testInsertSucceedsWithAutoUuidForSQLite(): void
 | 
						|
    {
 | 
						|
        $query = Query::insert('test_tbl', AutoId::UUID);
 | 
						|
        $this->assertStringStartsWith("INSERT INTO test_tbl VALUES (json_set(:data, '$.id', '", $query,
 | 
						|
            'INSERT statement not constructed correctly');
 | 
						|
        $this->assertStringEndsWith("'))", $query, 'INSERT statement not constructed correctly');
 | 
						|
    }
 | 
						|
 | 
						|
    #[TestDox('insert() succeeds with auto random string for PostgreSQL')]
 | 
						|
    public function testInsertSucceedsWithAutoRandomStringForPostgreSQL(): void
 | 
						|
    {
 | 
						|
        Configuration::overrideMode(Mode::PgSQL);
 | 
						|
        Configuration::$idStringLength = 8;
 | 
						|
        try {
 | 
						|
            $query = Query::insert('test_tbl', AutoId::RandomString);
 | 
						|
            $this->assertStringStartsWith("INSERT INTO test_tbl VALUES (:data::jsonb || '{\"id\":\"", $query,
 | 
						|
                'INSERT statement not constructed correctly');
 | 
						|
            $this->assertStringEndsWith("\"}')", $query, 'INSERT statement not constructed correctly');
 | 
						|
            $id = str_replace(["INSERT INTO test_tbl VALUES (:data::jsonb || '{\"id\":\"", "\"}')"], '', $query);
 | 
						|
            $this->assertEquals(8, strlen($id), "Generated ID [$id] should have been 8 characters long");
 | 
						|
        } finally {
 | 
						|
            Configuration::$idStringLength = 16;
 | 
						|
        }
 | 
						|
    }
 | 
						|
 | 
						|
    #[TestDox('insert() succeeds with auto random string for SQLite')]
 | 
						|
    public function testInsertSucceedsWithAutoRandomStringForSQLite(): void
 | 
						|
    {
 | 
						|
        $query = Query::insert('test_tbl', AutoId::RandomString);
 | 
						|
        $this->assertStringStartsWith("INSERT INTO test_tbl VALUES (json_set(:data, '$.id', '", $query,
 | 
						|
            'INSERT statement not constructed correctly');
 | 
						|
        $this->assertStringEndsWith("'))", $query, 'INSERT statement not constructed correctly');
 | 
						|
        $id = str_replace(["INSERT INTO test_tbl VALUES (json_set(:data, '$.id', '", "'))"], '', $query);
 | 
						|
        $this->assertEquals(16, strlen($id), "Generated ID [$id] should have been 16 characters long");
 | 
						|
    }
 | 
						|
 | 
						|
    #[TestDox('insert() fails when mode not set')]
 | 
						|
    public function testInsertFailsWhenModeNotSet(): void
 | 
						|
    {
 | 
						|
        $this->expectException(DocumentException::class);
 | 
						|
        Configuration::overrideMode(null);
 | 
						|
        Query::insert('kaboom');
 | 
						|
    }
 | 
						|
 | 
						|
    #[TestDox('save() succeeds')]
 | 
						|
    public function testSaveSucceeds(): void
 | 
						|
    {
 | 
						|
        $this->assertEquals(
 | 
						|
            "INSERT INTO test_tbl VALUES (:data) ON CONFLICT ((data->>'id')) DO UPDATE SET data = EXCLUDED.data",
 | 
						|
            Query::save('test_tbl'), 'INSERT ON CONFLICT statement not constructed correctly');
 | 
						|
    }
 | 
						|
 | 
						|
    #[TestDox('update() succeeds')]
 | 
						|
    public function testUpdateSucceeds(): void
 | 
						|
    {
 | 
						|
        $this->assertEquals("UPDATE testing SET data = :data WHERE data->>'id' = :id", Query::update('testing'),
 | 
						|
            'UPDATE statement not constructed correctly');
 | 
						|
    }
 | 
						|
 | 
						|
    #[TestDox('orderBy() succeeds with no fields for PostgreSQL')]
 | 
						|
    public function testOrderBySucceedsWithNoFieldsForPostgreSQL(): void
 | 
						|
    {
 | 
						|
        Configuration::overrideMode(Mode::PgSQL);
 | 
						|
        $this->assertEquals('', Query::orderBy([]), 'ORDER BY should have been blank');
 | 
						|
    }
 | 
						|
 | 
						|
    #[TestDox('orderBy() succeeds with no fields for SQLite')]
 | 
						|
    public function testOrderBySucceedsWithNoFieldsForSQLite(): void
 | 
						|
    {
 | 
						|
        $this->assertEquals('', Query::orderBy([]), 'ORDER BY should have been blank');
 | 
						|
    }
 | 
						|
 | 
						|
    #[TestDox('orderBy() succeeds with one field and no direction for PostgreSQL')]
 | 
						|
    public function testOrderBySucceedsWithOneFieldAndNoDirectionForPostgreSQL(): void
 | 
						|
    {
 | 
						|
        Configuration::overrideMode(Mode::PgSQL);
 | 
						|
        $this->assertEquals(" ORDER BY data->>'TestField'", Query::orderBy([Field::named('TestField')]),
 | 
						|
            'ORDER BY not constructed correctly');
 | 
						|
    }
 | 
						|
 | 
						|
    #[TestDox('orderBy() succeeds with one field and no direction for SQLite')]
 | 
						|
    public function testOrderBySucceedsWithOneFieldAndNoDirectionForSQLite(): void
 | 
						|
    {
 | 
						|
        $this->assertEquals(" ORDER BY data->>'TestField'", Query::orderBy([Field::named('TestField')]),
 | 
						|
            'ORDER BY not constructed correctly');
 | 
						|
    }
 | 
						|
 | 
						|
    #[TestDox('orderBy() succeeds with one qualified field for PostgreSQL')]
 | 
						|
    public function testOrderBySucceedsWithOneQualifiedFieldForPostgreSQL(): void
 | 
						|
    {
 | 
						|
        Configuration::overrideMode(Mode::PgSQL);
 | 
						|
        $field = Field::named('TestField');
 | 
						|
        $field->qualifier = 'qual';
 | 
						|
        $this->assertEquals(" ORDER BY qual.data->>'TestField'", Query::orderBy([$field]),
 | 
						|
            'ORDER BY not constructed correctly');
 | 
						|
    }
 | 
						|
 | 
						|
    #[TestDox('orderBy() succeeds with one qualified field for SQLite')]
 | 
						|
    public function testOrderBySucceedsWithOneQualifiedFieldForSQLite(): void
 | 
						|
    {
 | 
						|
        $field = Field::named('TestField');
 | 
						|
        $field->qualifier = 'qual';
 | 
						|
        $this->assertEquals(" ORDER BY qual.data->>'TestField'", Query::orderBy([$field]),
 | 
						|
            'ORDER BY not constructed correctly');
 | 
						|
    }
 | 
						|
 | 
						|
    #[TestDox('orderBy() succeeds with multiple fields and direction for PostgreSQL')]
 | 
						|
    public function testOrderBySucceedsWithMultipleFieldsAndDirectionForPostgreSQL(): void
 | 
						|
    {
 | 
						|
        Configuration::overrideMode(Mode::PgSQL);
 | 
						|
        $this->assertEquals(" ORDER BY data#>>'{Nested,Test,Field}' DESC, data->>'AnotherField', data->>'It' DESC",
 | 
						|
            Query::orderBy(
 | 
						|
                [Field::named('Nested.Test.Field DESC'), Field::named('AnotherField'), Field::named('It DESC')]),
 | 
						|
            'ORDER BY not constructed correctly');
 | 
						|
    }
 | 
						|
 | 
						|
    #[TestDox('orderBy() succeeds with multiple fields and direction for SQLite')]
 | 
						|
    public function testOrderBySucceedsWithMultipleFieldsAndDirectionForSQLite(): void
 | 
						|
    {
 | 
						|
        $this->assertEquals(" ORDER BY data->'Nested'->'Test'->>'Field' DESC, data->>'AnotherField', data->>'It' DESC",
 | 
						|
            Query::orderBy(
 | 
						|
                [Field::named('Nested.Test.Field DESC'), Field::named('AnotherField'), Field::named('It DESC')]),
 | 
						|
            'ORDER BY not constructed correctly');
 | 
						|
    }
 | 
						|
 | 
						|
    #[TestDox('orderBy() succeeds with numeric field for PostgreSQL')]
 | 
						|
    public function testOrderBySucceedsWithNumericFieldForPostgreSQL(): void
 | 
						|
    {
 | 
						|
        Configuration::overrideMode(Mode::PgSQL);
 | 
						|
        $this->assertEquals(" ORDER BY (data->>'Test')::numeric", Query::orderBy([Field::named('n:Test')]),
 | 
						|
            'ORDER BY not constructed correctly');
 | 
						|
    }
 | 
						|
 | 
						|
    #[TestDox('orderBy() succeeds with numeric field for SQLite')]
 | 
						|
    public function testOrderBySucceedsWithNumericFieldForSQLite(): void
 | 
						|
    {
 | 
						|
        $this->assertEquals(" ORDER BY data->>'Test'", Query::orderBy([Field::named('n:Test')]),
 | 
						|
            'ORDER BY not constructed correctly');
 | 
						|
    }
 | 
						|
 | 
						|
    #[TestDox('orderBy() succeeds with case-insensitive ordering for PostgreSQL')]
 | 
						|
    public function testOrderBySucceedsWithCaseInsensitiveOrderingForPostgreSQL(): void
 | 
						|
    {
 | 
						|
        Configuration::overrideMode(Mode::PgSQL);
 | 
						|
        $this->assertEquals(" ORDER BY LOWER(data#>>'{Test,Field}') DESC NULLS FIRST",
 | 
						|
            Query::orderBy([Field::named('i:Test.Field DESC NULLS FIRST')]), 'ORDER BY not constructed correctly');
 | 
						|
    }
 | 
						|
 | 
						|
    #[TestDox('orderBy() succeeds with case-insensitive ordering for SQLite')]
 | 
						|
    public function testOrderBySucceedsWithCaseInsensitiveOrderingForSQLite(): void
 | 
						|
    {
 | 
						|
        $this->assertEquals(" ORDER BY data->'Test'->>'Field' COLLATE NOCASE ASC NULLS LAST",
 | 
						|
            Query::orderBy([Field::named('i:Test.Field ASC NULLS LAST')]), 'ORDER BY not constructed correctly');
 | 
						|
    }
 | 
						|
}
 |