diff --git a/src/Oci8/Query/Grammars/OracleGrammar.php b/src/Oci8/Query/Grammars/OracleGrammar.php index 0888bd03..b425b5ce 100644 --- a/src/Oci8/Query/Grammars/OracleGrammar.php +++ b/src/Oci8/Query/Grammars/OracleGrammar.php @@ -29,6 +29,11 @@ class OracleGrammar extends Grammar */ protected $maxLength; + /** + * @var int + */ + protected $labelSearchFullText = 1; + /** * Compile a delete statement with joins into SQL. * @@ -597,6 +602,40 @@ protected function whereInRaw(Builder $query, $where) return '0 = 1'; } + /** + * Compile a "where fulltext" clause. + * + * @param \Illuminate\Database\Query\Builder $query + * @param array $where + * @return string + */ + public function whereFullText(Builder $query, $where) + { + // Build the fullText clause + $fullTextClause = collect($where['columns']) + ->map(function ($column, $index) use ($where) { + $labelSearchFullText = $index > 0 ? ++$this->labelSearchFullText : $this->labelSearchFullText; + + return "CONTAINS({$this->wrap($column)}, {$this->parameter($where['value'])}, {$labelSearchFullText}) > 0"; + }) + ->implode(" {$where['boolean']} "); + + // Count the total number of columns in the clauses + $fullTextClauseCount = array_reduce($query->wheres, function ($count, $queryWhere) { + return $queryWhere['type'] === 'Fulltext' ? $count + count($queryWhere['columns']) : $count; + }, 0); + + // Reset the counter if all columns were used in the clause + if ($fullTextClauseCount === $this->labelSearchFullText) { + $this->labelSearchFullText = 0; + } + + // Increment the counter for the next clause + $this->labelSearchFullText++; + + return $fullTextClause; + } + private function resolveClause($column, $values, $type) { $chunks = array_chunk($values, 1000); diff --git a/src/Oci8/Schema/Grammars/OracleGrammar.php b/src/Oci8/Schema/Grammars/OracleGrammar.php index 069ed9cd..5c6f34ca 100644 --- a/src/Oci8/Schema/Grammars/OracleGrammar.php +++ b/src/Oci8/Schema/Grammars/OracleGrammar.php @@ -306,6 +306,42 @@ public function compileIndex(Blueprint $blueprint, Fluent $command) return "create index {$command->index} on ".$this->wrapTable($blueprint).' ( '.$this->columnize($command->columns).' )'; } + /** + * Compile a fulltext index key command. + * + * @param \Illuminate\Database\Schema\Blueprint $blueprint + * @param \Illuminate\Support\Fluent $command + * @return string + */ + public function compileFullText(Blueprint $blueprint, Fluent $command): string + { + $tableName = $this->wrapTable($blueprint); + $columns = $command->columns; + $indexBaseName = $command->index; + $preferenceName = $indexBaseName.'_preference'; + + $sqlStatements = []; + + foreach ($columns as $key => $column) { + $indexName = $indexBaseName; + $parametersIndex = ''; + + if (count($columns) > 1) { + $indexName .= "_{$key}"; + $parametersIndex = "datastore {$preferenceName} "; + } + + $parametersIndex .= 'sync(on commit)'; + + $sql = "execute immediate 'create index {$indexName} on $tableName ($column) indextype is + ctxsys.context parameters (''$parametersIndex'')';"; + + $sqlStatements[] = $sql; + } + + return 'begin '.implode(' ', $sqlStatements).' end;'; + } + /** * Compile a drop table command. * @@ -326,7 +362,7 @@ public function compileDrop(Blueprint $blueprint, Fluent $command) public function compileDropAllTables() { return 'BEGIN - FOR c IN (SELECT table_name FROM user_tables) LOOP + FOR c IN (SELECT table_name FROM user_tables WHERE secondary = \'N\') LOOP EXECUTE IMMEDIATE (\'DROP TABLE "\' || c.table_name || \'" CASCADE CONSTRAINTS\'); END LOOP; @@ -440,6 +476,33 @@ public function compileDropForeign(Blueprint $blueprint, Fluent $command) return $this->dropConstraint($blueprint, $command, 'foreign'); } + /** + * Compile a drop fulltext index command. + * + * @param \Illuminate\Database\Schema\Blueprint $blueprint + * @param \Illuminate\Support\Fluent $command + * @return string + */ + public function compileDropFullText(Blueprint $blueprint, Fluent $command): string + { + $columns = $command->columns; + + if (empty($columns)) { + return $this->compileDropIndex($blueprint, $command); + } + + $columns = array_map(function ($column) { + return "'".strtoupper($column)."'"; + }, $columns); + $columns = implode(', ', $columns); + + $dropFullTextSql = "for idx_rec in (select idx_name from ctx_user_indexes where idx_text_name in ($columns)) loop + execute immediate 'drop index ' || idx_rec.idx_name; + end loop;"; + + return "begin $dropFullTextSql end;"; + } + /** * Compile a rename table command. * diff --git a/src/Oci8/Schema/OracleBuilder.php b/src/Oci8/Schema/OracleBuilder.php index 1b778909..91afb56e 100644 --- a/src/Oci8/Schema/OracleBuilder.php +++ b/src/Oci8/Schema/OracleBuilder.php @@ -18,6 +18,11 @@ class OracleBuilder extends Builder */ public $comment; + /** + * @var \Yajra\Oci8\Schema\OraclePreferences + */ + public $ctxDdlPreferences; + /** * @param Connection $connection */ @@ -26,6 +31,7 @@ public function __construct(Connection $connection) parent::__construct($connection); $this->helper = new OracleAutoIncrementHelper($connection); $this->comment = new Comment($connection); + $this->ctxDdlPreferences = new OraclePreferences($connection); } /** @@ -43,6 +49,8 @@ public function create($table, Closure $callback) $callback($blueprint); + $this->ctxDdlPreferences->createPreferences($blueprint); + $this->build($blueprint); $this->comment->setComments($blueprint); @@ -99,6 +107,7 @@ public function table($table, Closure $callback) public function drop($table) { $this->helper->dropAutoIncrementObjects($table); + $this->ctxDdlPreferences->dropPreferencesByTable($table); parent::drop($table); } @@ -109,6 +118,7 @@ public function drop($table) */ public function dropAllTables() { + $this->ctxDdlPreferences->dropAllPreferences(); $this->connection->statement($this->grammar->compileDropAllTables()); } @@ -121,6 +131,7 @@ public function dropAllTables() public function dropIfExists($table) { $this->helper->dropAutoIncrementObjects($table); + $this->ctxDdlPreferences->dropPreferencesByTable($table); parent::dropIfExists($table); } diff --git a/src/Oci8/Schema/OraclePreferences.php b/src/Oci8/Schema/OraclePreferences.php new file mode 100644 index 00000000..b146aca0 --- /dev/null +++ b/src/Oci8/Schema/OraclePreferences.php @@ -0,0 +1,151 @@ +connection = $connection; + } + + /** + * Create a preferences values to use in index fullText. + * + * @param \Illuminate\Database\Schema\Blueprint $blueprint + * @return null + */ + public function createPreferences(Blueprint $blueprint): void + { + $this->setPreferenceFullText($blueprint); + + $sql = $this->generateSqlCreatePreferences(); + + if (! empty($sql)) { + $this->connection->statement( + "BEGIN $sql END;" + ); + } + } + + /** + * Generate script sql to create preferences. + * + * @param ?string $objectNameOracle + * @param ?string $attributeNameOracle + * @return string + */ + protected function generateSqlCreatePreferences( + ?string $objectNameOracle = 'MULTI_COLUMN_DATASTORE', + ?string $attributeNameOracle = 'COLUMNS' + ): string { + $ctxDdlCreatePreferences = []; + + foreach ($this->columns as $key => $columns) { + $preferenceName = $this->preferenceName[$key]; + $formattedColumns = $this->formatMultipleCtxColumns($columns); + + $ctxDdlCreatePreferences[] = "ctx_ddl.create_preference('{$preferenceName}', '{$objectNameOracle}'); + ctx_ddl.set_attribute('{$preferenceName}', '{$attributeNameOracle}', '{$formattedColumns}');"; + } + + return implode(' ', $ctxDdlCreatePreferences); + } + + /** + * Set columns and preference name to class attributes. + * + * @param \Illuminate\Database\Schema\Blueprint $blueprint + * @return void + */ + public function setPreferenceFullText(Blueprint $blueprint): void + { + $this->columns = []; + $this->preferenceName = []; + + foreach ($blueprint->getCommands() as $value) { + if ($value['name'] === 'fulltext' && count($value['columns']) > 1) { + $this->columns[] = $value['columns']; + $this->preferenceName[] = $value['index'].'_preference'; + } + } + } + + /** + * Format with "implode" function columns to use in preferences. + * + * @param array $columns + * @return string + */ + protected function formatMultipleCtxColumns(array $columns): string + { + return implode(', ', $columns); + } + + /** + * Drop preferences by specified table. + * + * @param string $table + * @return void + */ + public function dropPreferencesByTable(string $table): void + { + $sqlDropPreferencesByTable = "BEGIN + FOR c IN (select distinct (substr(cui.idx_name, 1, instr(cui.idx_name, '_', -1, 1) - 1) || '_preference') preference + from + ctxsys.ctx_user_indexes cui + where + cui.idx_table = ?) LOOP + EXECUTE IMMEDIATE 'BEGIN ctx_ddl.drop_preference(:preference); END;' + USING c.preference; + END LOOP; + END;"; + + $this->connection->statement($sqlDropPreferencesByTable, [ + strtoupper($table), + ]); + } + + /** + * Drop all user preferences. + * + * @return void + */ + public function dropAllPreferences(): void + { + $sqlDropAllPreferences = "BEGIN + FOR c IN (SELECT pre_name FROM ctx_user_preferences) LOOP + EXECUTE IMMEDIATE 'BEGIN ctx_ddl.drop_preference(:pre_name); END;' + USING c.pre_name; + END LOOP; + END;"; + + $this->connection->statement($sqlDropAllPreferences); + } +} diff --git a/tests/Database/Oci8QueryBuilderTest.php b/tests/Database/Oci8QueryBuilderTest.php index f71c50da..d2896402 100644 --- a/tests/Database/Oci8QueryBuilderTest.php +++ b/tests/Database/Oci8QueryBuilderTest.php @@ -718,6 +718,49 @@ public function testArrayWhereColumn() $this->assertEquals([], $builder->getBindings()); } + public function testWhereFullTextWithSingleParameter() + { + $builder = $this->getBuilder(); + $builder->select('*')->from('users')->whereFullText('name', 'johnny'); + $this->assertSame('select * from "USERS" where CONTAINS("NAME", ?, 1) > 0', $builder->toSql()); + $this->assertEquals(['johnny'], $builder->getBindings()); + } + + public function testWhereFullTextWithMultipleParameters() + { + $builder = $this->getBuilder(); + $builder->select('*')->from('users')->whereFullText(['firstname', 'lastname'], 'johnny'); + $this->assertSame('select * from "USERS" where CONTAINS("FIRSTNAME", ?, 1) > 0 and CONTAINS("LASTNAME", ?, 2) > 0', + $builder->toSql()); + $this->assertEquals(['johnny'], $builder->getBindings()); + } + + public function testWhereFullTextWithLogicalOrOperator() + { + $builder = $this->getBuilder(); + $builder->select('*')->from('users')->whereFullText(['firstname', 'lastname'], 'johnny', [], 'or'); + $this->assertSame('select * from "USERS" where CONTAINS("FIRSTNAME", ?, 1) > 0 or CONTAINS("LASTNAME", ?, 2) > 0', + $builder->toSql()); + $this->assertEquals(['johnny'], $builder->getBindings()); + } + + public function testOrWhereFullTextWithSingleParameter() + { + $builder = $this->getBuilder(); + $builder->select('*')->from('users')->orWhereFullText('firstname', 'johnny'); + $this->assertSame('select * from "USERS" where CONTAINS("FIRSTNAME", ?, 1) > 0', $builder->toSql()); + $this->assertEquals(['johnny'], $builder->getBindings()); + } + + public function testOrWhereFullTextWithMultipleParameters() + { + $builder = $this->getBuilder(); + $builder->select('*')->from('users')->orWhereFullText('firstname', 'johnny')->orWhereFullText('lastname', 'white'); + $this->assertSame('select * from "USERS" where CONTAINS("FIRSTNAME", ?, 1) > 0 or CONTAINS("LASTNAME", ?, 2) > 0', + $builder->toSql()); + $this->assertEquals(['johnny', 'white'], $builder->getBindings()); + } + public function testUnions() { $builder = $this->getBuilder(); diff --git a/tests/Database/Oci8SchemaGrammarTest.php b/tests/Database/Oci8SchemaGrammarTest.php index c6253be4..1de1d441 100644 --- a/tests/Database/Oci8SchemaGrammarTest.php +++ b/tests/Database/Oci8SchemaGrammarTest.php @@ -381,6 +381,30 @@ public function testDropTimestamps() $this->assertEquals('alter table users drop ( created_at, updated_at )', $statements[0]); } + public function testSingleDropFullTextByIndex() + { + $blueprint = new Blueprint('users'); + $blueprint->dropFullText('name_index'); + $statements = $blueprint->toSql($this->getConnection(), $this->getGrammar()); + + $this->assertEquals(1, count($statements)); + $this->assertEquals('drop index name_index', $statements[0]); + } + + public function testMultipleDropFullTextByColumns() + { + $blueprint = new Blueprint('users'); + $blueprint->dropFullText(['firstname', 'lastname']); + $statements = $blueprint->toSql($this->getConnection(), $this->getGrammar()); + + $expected = "begin for idx_rec in (select idx_name from ctx_user_indexes where idx_text_name in ('FIRSTNAME', 'LASTNAME')) loop + execute immediate 'drop index ' || idx_rec.idx_name; + end loop; end;"; + + $this->assertEquals(1, count($statements)); + $this->assertEquals($expected, $statements[0]); + } + public function testRenameTable() { $blueprint = new Blueprint('users'); @@ -487,6 +511,35 @@ public function testAddingIndex() $this->assertEquals('create index baz on users ( foo, bar )', $statements[0]); } + public function testAddingMSingleColumnFullTextIndex() + { + $blueprint = new Blueprint('users'); + $blueprint->fullText(['name'], 'name'); + $statements = $blueprint->toSql($this->getConnection(), $this->getGrammar()); + + $expected = "begin execute immediate 'create index name on users (name) indextype is + ctxsys.context parameters (''sync(on commit)'')'; end;"; + + $this->assertEquals(1, count($statements)); + $this->assertEquals($expected, $statements[0]); + } + + public function testAddingMultipleColumnsFullTextIndex() + { + $blueprint = new Blueprint('users'); + $blueprint->fullText(['firstname', 'lastname'], 'name'); + $statements = $blueprint->toSql($this->getConnection(), $this->getGrammar()); + + $expectedSql['firstnameIndex'] = "execute immediate 'create index name_0 on users (firstname) indextype is + ctxsys.context parameters (''datastore name_preference sync(on commit)'')';"; + $expectedSql['lastnameIndex'] = "execute immediate 'create index name_1 on users (lastname) indextype is + ctxsys.context parameters (''datastore name_preference sync(on commit)'')';"; + $expected = 'begin '.implode(' ', $expectedSql).' end;'; + + $this->assertEquals(1, count($statements)); + $this->assertEquals($expected, $statements[0]); + } + public function testAddingForeignKey() { $blueprint = new Blueprint('users'); @@ -877,7 +930,7 @@ public function testDropAllTables() $statement = $this->getGrammar()->compileDropAllTables(); $expected = 'BEGIN - FOR c IN (SELECT table_name FROM user_tables) LOOP + FOR c IN (SELECT table_name FROM user_tables WHERE secondary = \'N\') LOOP EXECUTE IMMEDIATE (\'DROP TABLE "\' || c.table_name || \'" CASCADE CONSTRAINTS\'); END LOOP; diff --git a/tests/Database/OraclePreferencesTest.php b/tests/Database/OraclePreferencesTest.php new file mode 100644 index 00000000..2423a000 --- /dev/null +++ b/tests/Database/OraclePreferencesTest.php @@ -0,0 +1,134 @@ +getConnection(); + $oraclePreferences = new OraclePreferences($connection); + + $connection->shouldReceive('statement') + ->andReturnUsing(function () { + $this->assertTrue(false, 'A single full-text column cannot create preferences.'); + }); + + $blueprint = new Blueprint('users'); + $blueprint->fullText('name', 'name_search_full_text'); + + $oraclePreferences->createPreferences($blueprint); + + $this->assertTrue(true); + } + + public function testCreatePreferencesWithMultipleFullText() + { + $connection = $this->getConnection(); + $oraclePreferences = new OraclePreferences($connection); + + $expected = "BEGIN ctx_ddl.create_preference('name_preference', 'MULTI_COLUMN_DATASTORE'); + ctx_ddl.set_attribute('name_preference', 'COLUMNS', 'firstname, lastname'); END;"; + + $connection->shouldReceive('statement') + ->once() + ->andReturnUsing(function ($sql) use ($expected) { + $this->assertEquals($expected, $sql); + }); + + $blueprint = new Blueprint('users'); + $blueprint->fullText(['firstname', 'lastname'], 'name'); + + $oraclePreferences->createPreferences($blueprint); + } + + public function testCreatePreferencesWithOtherMultipleFullText() + { + $connection = $this->getConnection(); + $oraclePreferences = new OraclePreferences($connection); + + $preferences['name_preference'] = "ctx_ddl.create_preference('name_preference', 'MULTI_COLUMN_DATASTORE'); + ctx_ddl.set_attribute('name_preference', 'COLUMNS', 'firstname, lastname');"; + $preferences['product_preference'] = "ctx_ddl.create_preference('product_preference', 'MULTI_COLUMN_DATASTORE'); + ctx_ddl.set_attribute('product_preference', 'COLUMNS', 'category, price');"; + + $expected = 'BEGIN '.implode(' ', $preferences).' END;'; + + $connection->shouldReceive('statement') + ->once() + ->andReturnUsing(function ($sql) use ($expected) { + $this->assertEquals($expected, $sql); + }); + + $blueprint = new Blueprint('users_product'); + $blueprint->fullText(['firstname', 'lastname'], 'name'); + $blueprint->fullText(['category', 'price'], 'product'); + + $oraclePreferences->createPreferences($blueprint); + } + + public function testDropAllPreferencesByTable() + { + $connection = $this->getConnection(); + $oraclePreferences = new OraclePreferences($connection); + + $expected = "BEGIN + FOR c IN (select distinct (substr(cui.idx_name, 1, instr(cui.idx_name, '_', -1, 1) - 1) || '_preference') preference + from + ctxsys.ctx_user_indexes cui + where + cui.idx_table = ?) LOOP + EXECUTE IMMEDIATE 'BEGIN ctx_ddl.drop_preference(:preference); END;' + USING c.preference; + END LOOP; + END;"; + + $connection->shouldReceive('statement') + ->once() + ->andReturnUsing(function ($sql, $bindings) use ($expected) { + $this->assertSame($expected, $sql); + $this->assertSame(['USERS'], $bindings); + }); + + $oraclePreferences->dropPreferencesByTable('users'); + } + + public function testDropAllPreferences() + { + $connection = $this->getConnection(); + $oraclePreferences = new OraclePreferences($connection); + + $expected = "BEGIN + FOR c IN (SELECT pre_name FROM ctx_user_preferences) LOOP + EXECUTE IMMEDIATE 'BEGIN ctx_ddl.drop_preference(:pre_name); END;' + USING c.pre_name; + END LOOP; + END;"; + + $connection->shouldReceive('statement') + ->once() + ->andReturnUsing(function ($sql) use ($expected) { + $this->assertEquals($expected, $sql); + }); + + $oraclePreferences->dropAllPreferences(); + } + + protected function getConnection() + { + return m::mock('Illuminate\Database\Connection'); + } +}