├── .travis.yml ├── LICENSE ├── Query ├── JsonbAtGreater.php ├── JsonbExistence.php └── JsonbHashGreaterGreater.php ├── README.md ├── Tests ├── BaseTest.php ├── Entities │ └── Test.php ├── IntegrationTest │ └── IntegrationTest.php ├── Query │ ├── JsonbAtGreaterTest.php │ ├── JsonbExistenceTest.php │ └── JsonbHashGreaterGreaterTest.php └── bootstrap.php ├── Types └── JsonbArrayType.php ├── composer.json └── phpunit.xml.dist /.travis.yml: -------------------------------------------------------------------------------- 1 | language: php 2 | 3 | php: 4 | - 7.3 5 | 6 | addons: 7 | postgresql: "9.6" 8 | 9 | before_script: 10 | - psql -c 'create database jsonb_test;' -U postgres 11 | - composer install -n --no-interaction --prefer-source 12 | 13 | script: 14 | - phpunit 15 | 16 | notifications: 17 | email: boldtrn@gmail.com 18 | -------------------------------------------------------------------------------- /LICENSE: -------------------------------------------------------------------------------- 1 | MIT License 2 | 3 | Copyright (c) 2020 Robin Boldt 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 | -------------------------------------------------------------------------------- /Query/JsonbAtGreater.php: -------------------------------------------------------------------------------- 1 | RightHandSide )" 15 | * 16 | * @package Boldtrn\JsonbBundle\Query 17 | * @author Robin Boldt 18 | */ 19 | class JsonbAtGreater extends FunctionNode 20 | { 21 | public $leftHandSide = null; 22 | public $rightHandSide = null; 23 | 24 | public function parse(\Doctrine\ORM\Query\Parser $parser) 25 | { 26 | $parser->match(Lexer::T_IDENTIFIER); 27 | $parser->match(Lexer::T_OPEN_PARENTHESIS); 28 | $this->leftHandSide = $parser->ArithmeticPrimary(); 29 | $parser->match(Lexer::T_COMMA); 30 | $this->rightHandSide = $parser->ArithmeticPrimary(); 31 | $parser->match(Lexer::T_CLOSE_PARENTHESIS); 32 | } 33 | 34 | public function getSql(\Doctrine\ORM\Query\SqlWalker $sqlWalker) 35 | { 36 | // We use a workaround to allow this statement in a WHERE. Doctrine relies on the existence of an ComparisonOperator 37 | return '(' . 38 | $this->leftHandSide->dispatch($sqlWalker) . ' @> ' . 39 | $this->rightHandSide->dispatch($sqlWalker) . 40 | ')'; 41 | } 42 | } -------------------------------------------------------------------------------- /Query/JsonbExistence.php: -------------------------------------------------------------------------------- 1 | 18 | */ 19 | class JsonbExistence extends FunctionNode 20 | { 21 | public $leftHandSide = null; 22 | public $rightHandSide = null; 23 | 24 | public function parse(\Doctrine\ORM\Query\Parser $parser) 25 | { 26 | $parser->match(Lexer::T_IDENTIFIER); 27 | $parser->match(Lexer::T_OPEN_PARENTHESIS); 28 | $this->leftHandSide = $parser->ArithmeticPrimary(); 29 | $parser->match(Lexer::T_COMMA); 30 | $this->rightHandSide = $parser->ArithmeticPrimary(); 31 | $parser->match(Lexer::T_CLOSE_PARENTHESIS); 32 | } 33 | 34 | public function getSql(\Doctrine\ORM\Query\SqlWalker $sqlWalker) 35 | { 36 | // We use a workaround to allow this statement in a WHERE. Doctrine relies on the existence of an ComparisonOperator 37 | return 'jsonb_exists(' . 38 | $this->leftHandSide->dispatch($sqlWalker) .', '. 39 | $this->rightHandSide->dispatch($sqlWalker) . 40 | ')'; 41 | } 42 | } 43 | -------------------------------------------------------------------------------- /Query/JsonbHashGreaterGreater.php: -------------------------------------------------------------------------------- 1 | >" "(" LeftHandSide "," RightHandSide ")" 14 | * 15 | * This will be converted to: "( LeftHandSide #>> RightHandSide )" 16 | * 17 | * @package Boldtrn\JsonbBundle\Query 18 | * @author Robin Boldt 19 | */ 20 | class JsonbHashGreaterGreater extends FunctionNode 21 | { 22 | public $rightHandSide = null; 23 | public $leftHandSide = null; 24 | 25 | public function parse(\Doctrine\ORM\Query\Parser $parser) 26 | { 27 | $parser->match(Lexer::T_IDENTIFIER); 28 | $parser->match(Lexer::T_OPEN_PARENTHESIS); 29 | $this->rightHandSide = $parser->ArithmeticPrimary(); 30 | $parser->match(Lexer::T_COMMA); 31 | $this->leftHandSide = $parser->ArithmeticPrimary(); 32 | $parser->match(Lexer::T_CLOSE_PARENTHESIS); 33 | } 34 | 35 | public function getSql(\Doctrine\ORM\Query\SqlWalker $sqlWalker) 36 | { 37 | return '(' . 38 | $this->rightHandSide->dispatch($sqlWalker) . ' #>> ' . 39 | $this->leftHandSide->dispatch($sqlWalker) . 40 | ')'; 41 | } 42 | } -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | JsonbBundle 2 | ============ 3 | 4 | **Doctrine implemented the `jsonb` datatype with Doctrine DBAL 2.6. I recommend using the official Doctrine implementation. If you cannot upgrade feel free to use this bundle. It still works for me in my current production setting. I will upgrade to the doctrine implementation at some point in time, as well.** 5 | **[Doctrine Mapping Matrix](http://doctrine-orm.readthedocs.org/projects/doctrine-dbal/en/latest/reference/types.html#mapping-matrix)** 6 | 7 | 8 | This bundle extends Doctrine to use the `jsonb` datatype that ships with Postgresql 9.4. 9 | This bundle is fully compatible with Symfony, but you do not have to use Symfony (see the `composer.json` for dependencies). 10 | Please make sure you have Postgresql with a version of at least 9.4 installed before using this bundle. 11 | The Bundle allows to create Jsonb fields and use the `@>`,`?` and the `#>>` operator on the Jsonb field. 12 | Other Operations can be easily added. 13 | 14 | I recently discovered the power of NativeQueries (http://doctrine-orm.readthedocs.org/en/latest/reference/native-sql.html). 15 | Right now I only use NativeQueries when querying. An example is shown below. 16 | 17 | [![Build Status](https://travis-ci.org/boldtrn/JsonbBundle.svg?branch=master)](https://travis-ci.org/boldtrn/JsonbBundle) 18 | 19 | Installation 20 | ============ 21 | 22 | Step 1: Download the Bundle 23 | --------------------------- 24 | 25 | Open a command console, enter your project directory and execute the 26 | following command to download the latest stable version of this bundle: 27 | 28 | ```bash 29 | $ composer require "boldtrn/jsonb-bundle:~1.1" 30 | ``` 31 | 32 | Step 2: Add the new Types and Functions to the Config 33 | ------------------------- 34 | 35 | ```yaml 36 | # config.yml 37 | doctrine: 38 | dbal: 39 | types: 40 | jsonb: Boldtrn\JsonbBundle\Types\JsonbArrayType 41 | mapping_types: 42 | jsonb: jsonb 43 | orm: 44 | dql: 45 | string_functions: 46 | JSONB_AG: Boldtrn\JsonbBundle\Query\JsonbAtGreater 47 | JSONB_HGG: Boldtrn\JsonbBundle\Query\JsonbHashGreaterGreater 48 | JSONB_EX: Boldtrn\JsonbBundle\Query\JsonbExistence 49 | ``` 50 | 51 | Note: There were people having issues with the above configuration. They had the following exception: 52 | ``` 53 | [Symfony\Component\Config\Definition\Exception\InvalidConfigurationException] 54 | Unrecognized options "dql" under "doctrine.orm" 55 | ``` 56 | 57 | This was fixed by changing the dql part in the following (add the `entity_managers` between `orm` and `dql`): 58 | ```yaml 59 | doctrine: 60 | orm: 61 | entity_managers: 62 | dql: 63 | ``` 64 | 65 | Step 3: Create a Entity and Use the Jsonb Type 66 | ------------------------- 67 | 68 | ```php 69 | /** 70 | * @Entity 71 | */ 72 | class Test 73 | { 74 | 75 | /** 76 | * @Id 77 | * @Column(type="string") 78 | * @GeneratedValue 79 | */ 80 | public $id; 81 | 82 | /** 83 | * @Column(type="jsonb") 84 | * 85 | * Usually attrs is an array, depends on you 86 | * 87 | */ 88 | public $attrs = array(); 89 | 90 | } 91 | ``` 92 | Step 4.1: Write a Repository Method using a NativeQuery 93 | ------------------------- 94 | 95 | ```php 96 | $q = $this 97 | ->entityManager 98 | ->createNativeQuery( 99 | " 100 | SELECT t.id, t.attrs 101 | FROM Test t 102 | WHERE t.attrs @> 'value' 103 | " 104 | , $rsm); 105 | ``` 106 | 107 | You only need to setup the `$rsm` ResultSetMapping according to the Doctrine documentation. 108 | 109 | Step 4.2: Write a Repository Method that queries for the jsonb using the custom JSONB_FUNCTIONS 110 | ------------------------- 111 | 112 | This example shows how to use the contains statement in a WHERE clause. 113 | The `= TRUE` is a workaround for Doctrine that needs an comparison operator in the WHERE clause. 114 | 115 | ```php 116 | $q = $this 117 | ->entityManager 118 | ->createQuery( 119 | " 120 | SELECT t 121 | FROM E:Test t 122 | WHERE JSONB_AG(t.attrs, 'value') = TRUE 123 | " 124 | ); 125 | ``` 126 | 127 | This produces the following Query: 128 | ```SQL 129 | SELECT t0_.id AS id0, t0_.attrs AS attrs1 FROM Test t0_ WHERE (t0_.attrs @> 'value') = true 130 | ``` 131 | 132 | This example shows how to query for a value that is LIKE `%d%` 133 | The result could be data like: 134 | ``` 135 | id | attrs 136 | ----+-------------------------------------- 137 | 4 | {"a": 1, "b": {"c": "abcdefg", "e": true}} 138 | ``` 139 | 140 | 141 | ```php 142 | $q = $this 143 | ->entityManager 144 | ->createQuery( 145 | " 146 | SELECT t 147 | FROM E:Test t 148 | WHERE JSONB_HGG(t.attrs , '{\"b\",\"c\"}') LIKE '%d%' 149 | " 150 | ); 151 | ``` 152 | 153 | This produces the following Query: 154 | ```SQL 155 | SELECT t0_.id AS id0, t0_.attrs AS attrs1 FROM Test t0_ WHERE (t0_.attrs #>> '{\"object1\",\"object2\"}') LIKE '%a%' 156 | ``` 157 | 158 | 159 | Further Information 160 | ------------------------- 161 | 162 | The `?` operator is implemented by calling its function `jsonb_exists(column_name, value)` since Doctrine will consider it a parameter placeholder otherwise. The same must be done if you want to implement `?|` and `?&` operators, using `jsonb_exists_any(column_name, value)` and `jsonb_exists_all(column_name, value)` respectively 163 | -------------------------------------------------------------------------------- /Tests/BaseTest.php: -------------------------------------------------------------------------------- 1 | 'pdo_pgsql', 30 | 'host' => 'localhost', 31 | 'port' => '5432', 32 | 'dbname' => 'jsonb_test', 33 | 'user' => 'postgres', 34 | 'password' => 'secret', 35 | ); 36 | 37 | protected $testEntityName = 'Boldtrn\JsonbBundle\Tests\Entities\Test'; 38 | 39 | protected function setUp() 40 | { 41 | 42 | if (!class_exists('\Doctrine\ORM\Configuration')) { 43 | static::markTestSkipped('Doctrine is not available'); 44 | } 45 | 46 | $config = new Configuration(); 47 | $config->setMetadataCacheImpl(new ArrayCache()); 48 | $config->setQueryCacheImpl(new ArrayCache()); 49 | $config->setProxyDir(__DIR__.'/Proxies'); 50 | $config->setProxyNamespace('Boldtrn\JsonbBundle\Tests\Proxies'); 51 | $config->setAutoGenerateProxyClasses(true); 52 | $config->setMetadataDriverImpl($config->newDefaultAnnotationDriver(__DIR__.'/Entities')); 53 | $config->addEntityNamespace('E', 'Boldtrn\JsonbBundle\Tests\Entities'); 54 | $config->setCustomStringFunctions( 55 | array( 56 | 'JSONB_AG' => 'Boldtrn\JsonbBundle\Query\JsonbAtGreater', 57 | 'JSONB_HGG' => 'Boldtrn\JsonbBundle\Query\JsonbHashGreaterGreater', 58 | 'JSONB_EX' => 'Boldtrn\JsonbBundle\Query\JsonbExistence', 59 | ) 60 | ); 61 | 62 | 63 | $this->entityManager = EntityManager::create( 64 | $this->dbParams, 65 | $config 66 | ); 67 | 68 | $this->connection = $this->entityManager->getConnection(); 69 | 70 | $this->setUpDBALTypes(); 71 | 72 | $tool = new SchemaTool($this->entityManager); 73 | $classes = $this->entityManager->getMetaDataFactory()->getAllMetaData(); 74 | 75 | 76 | // Drop all classes and re-build them for each test case 77 | $tool->dropSchema($classes); 78 | $tool->createSchema($classes); 79 | 80 | } 81 | 82 | /** 83 | * Configures DBAL types required in tests 84 | */ 85 | protected function setUpDBALTypes() 86 | { 87 | 88 | if (Type::hasType('jsonb')) { 89 | Type::overrideType('jsonb', 'Boldtrn\JsonbBundle\Types\JsonbArrayType'); 90 | } else { 91 | Type::addType('jsonb', 'Boldtrn\JsonbBundle\Types\JsonbArrayType'); 92 | } 93 | 94 | $this->connection->getDatabasePlatform()->registerDoctrineTypeMapping('JSONB', 'jsonb'); 95 | } 96 | 97 | } -------------------------------------------------------------------------------- /Tests/Entities/Test.php: -------------------------------------------------------------------------------- 1 | id; 34 | } 35 | 36 | /** 37 | * @return mixed 38 | */ 39 | public function getAttrs() 40 | { 41 | return $this->attrs; 42 | } 43 | 44 | /** 45 | * @param mixed $attrs 46 | */ 47 | public function setAttrs($attrs) 48 | { 49 | $this->attrs = $attrs; 50 | } 51 | 52 | } -------------------------------------------------------------------------------- /Tests/IntegrationTest/IntegrationTest.php: -------------------------------------------------------------------------------- 1 | createTest(array('foo' => 'bar')); 22 | 23 | /** @var Test $retrievedTest */ 24 | $retrievedTest = $this->entityManager->getRepository($this->testEntityName)->find($test->getId()); 25 | 26 | static::assertEquals($test->getAttrs(), $retrievedTest->getAttrs()); 27 | 28 | } 29 | 30 | public function testEmptyArray() 31 | { 32 | 33 | $test = $this->createTest(array()); 34 | 35 | /** @var Test $retrievedTest */ 36 | $retrievedTest = $this->entityManager->getRepository($this->testEntityName)->find($test->getId()); 37 | 38 | static::assertEquals($test->getAttrs(), $retrievedTest->getAttrs()); 39 | 40 | } 41 | 42 | /** 43 | * @param $attrs array the attributes of the jsonb array 44 | * @return Test 45 | */ 46 | private function createTest($attrs) 47 | { 48 | $test = new Test(); 49 | $test->setAttrs($attrs); 50 | 51 | $this->entityManager->persist($test); 52 | $this->entityManager->flush(); 53 | 54 | return $test; 55 | } 56 | 57 | private function clearTable() 58 | { 59 | 60 | foreach ($this->entityManager->getRepository($this->testEntityName)->findAll() as $test) { 61 | $this->entityManager->remove($test); 62 | } 63 | 64 | $this->entityManager->flush(); 65 | 66 | } 67 | 68 | } 69 | -------------------------------------------------------------------------------- /Tests/Query/JsonbAtGreaterTest.php: -------------------------------------------------------------------------------- 1 | entityManager 21 | ->createQuery( 22 | " 23 | SELECT t 24 | FROM E:Test t 25 | WHERE JSONB_AG(t.attrs, 'value') = TRUE 26 | " 27 | ); 28 | 29 | $expectedSQL = "SELECT t0_.id AS id0, t0_.attrs AS attrs1 FROM Test t0_ WHERE (t0_.attrs @> 'value') = true"; 30 | 31 | $expectedSQL = str_replace("_", "", $expectedSQL); 32 | 33 | $actualSQL = str_replace("_", "", $q->getSql()); 34 | 35 | $this->assertEquals( 36 | $expectedSQL, 37 | $actualSQL 38 | ); 39 | } 40 | 41 | } 42 | -------------------------------------------------------------------------------- /Tests/Query/JsonbExistenceTest.php: -------------------------------------------------------------------------------- 1 | entityManager 21 | ->createQuery( 22 | " 23 | SELECT t 24 | FROM E:Test t 25 | WHERE JSONB_EX(t.attrs, 'value') = TRUE 26 | " 27 | ); 28 | 29 | $expectedSQL = "SELECT t0.id AS id0, t0.attrs AS attrs1 FROM Test t0 WHERE jsonb_exists(t0.attrs, 'value') = true"; 30 | 31 | $expectedSQL = str_replace("_", "", $expectedSQL); 32 | 33 | $actualSQL = str_replace("_", "", $q->getSql()); 34 | 35 | $this->assertEquals( 36 | $expectedSQL, 37 | $actualSQL 38 | ); 39 | } 40 | 41 | } 42 | -------------------------------------------------------------------------------- /Tests/Query/JsonbHashGreaterGreaterTest.php: -------------------------------------------------------------------------------- 1 | entityManager 21 | ->createQuery( 22 | " 23 | SELECT t 24 | FROM E:Test t 25 | WHERE JSONB_HGG(t.attrs , '{\"object1\",\"object2\"}') LIKE '%a%' 26 | " 27 | ); 28 | 29 | $expectedSQL = "SELECT t0_.id AS id0, t0_.attrs AS attrs1 FROM Test t0_ WHERE (t0_.attrs #>> '{\"object1\",\"object2\"}') LIKE '%a%'"; 30 | 31 | $expectedSQL = str_replace("_", "", $expectedSQL); 32 | 33 | $actualSQL = str_replace("_", "", $q->getSql()); 34 | 35 | $this->assertEquals( 36 | $expectedSQL, 37 | $actualSQL 38 | ); 39 | 40 | } 41 | 42 | } 43 | -------------------------------------------------------------------------------- /Tests/bootstrap.php: -------------------------------------------------------------------------------- 1 | 11 | */ 12 | class JsonbArrayType extends JsonType 13 | { 14 | /** 15 | * {@inheritdoc} 16 | */ 17 | public function getSQLDeclaration(array $fieldDeclaration, AbstractPlatform $platform) 18 | { 19 | return 'JSONB'; 20 | } 21 | 22 | /** 23 | * {@inheritdoc} 24 | */ 25 | public function getName() 26 | { 27 | return 'jsonb'; 28 | } 29 | 30 | /** 31 | * {@inheritdoc} 32 | */ 33 | public function requiresSQLCommentHint(AbstractPlatform $platform) 34 | { 35 | return true; 36 | } 37 | 38 | } 39 | -------------------------------------------------------------------------------- /composer.json: -------------------------------------------------------------------------------- 1 | { 2 | "name": "boldtrn/jsonb-bundle", 3 | "license": "MIT", 4 | "type": "library", 5 | "description": "A library adding the support for JSONB columns of PostgreSQL to Doctrine.", 6 | "keywords": [ 7 | "jsonb", 8 | "doctrine", 9 | "symfony", 10 | "bundle", 11 | "postgresql" 12 | ], 13 | "homepage": "https://github.com/boldtrn/JsonbBundle", 14 | "autoload": { 15 | "psr-4": { 16 | "Boldtrn\\JsonbBundle\\": "" 17 | } 18 | }, 19 | "authors": [ 20 | { 21 | "name": "Robin Boldt", 22 | "email": "boldtrn@gmail.com" 23 | } 24 | ], 25 | "require": { 26 | "php": ">=5.3.3", 27 | "doctrine/dbal": "~2.4" 28 | }, 29 | "suggest": { 30 | "doctrine/orm": "To use DQL functions" 31 | }, 32 | "require-dev": { 33 | "doctrine/orm": ">2.4,<2.6", 34 | "phpunit/phpunit": "~4.2" 35 | } 36 | } 37 | -------------------------------------------------------------------------------- /phpunit.xml.dist: -------------------------------------------------------------------------------- 1 | 2 | 3 | 4 | 10 | 11 | 12 | ./Tests 13 | 14 | 15 | 16 | 21 | 22 | 23 | 24 | ./ 25 | 26 | ./Tests 27 | 28 | 29 | 30 | --------------------------------------------------------------------------------