Skip to content

Commit

Permalink
Merge pull request #800 from jonas-elias/jonas-elias_where-full-text
Browse files Browse the repository at this point in the history
feat: FullText Search in laravel-oci8
  • Loading branch information
yajra authored Feb 28, 2025
2 parents 492bf0d + c5b4fd9 commit 20a5624
Show file tree
Hide file tree
Showing 7 changed files with 494 additions and 0 deletions.
39 changes: 39 additions & 0 deletions src/Oci8/Query/Grammars/OracleGrammar.php
Original file line number Diff line number Diff line change
Expand Up @@ -33,6 +33,11 @@ public function __construct(Oci8Connection $connection)
$this->setMaxLength($connection->getMaxLength());
}

/**
* @var int
*/
protected $labelSearchFullText = 1;

/**
* Compile a delete statement with joins into SQL.
*
Expand Down Expand Up @@ -549,6 +554,40 @@ protected function whereInRaw(Builder $query, $where): string
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): string
{
$chunks = array_chunk($values, 1000);
Expand Down
63 changes: 63 additions & 0 deletions src/Oci8/Schema/Grammars/OracleGrammar.php
Original file line number Diff line number Diff line change
Expand Up @@ -324,6 +324,42 @@ public function compileIndex(Blueprint $blueprint, Fluent $command): string
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.
*/
Expand Down Expand Up @@ -434,6 +470,33 @@ public function compileDropForeign(Blueprint $blueprint, Fluent $command): strin
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.
*/
Expand Down
11 changes: 11 additions & 0 deletions src/Oci8/Schema/OracleBuilder.php
Original file line number Diff line number Diff line change
Expand Up @@ -17,11 +17,17 @@ class OracleBuilder extends Builder

public Comment $comment;

/**
* @var \Yajra\Oci8\Schema\OraclePreferences
*/
public $ctxDdlPreferences;

public function __construct(Oci8Connection $connection)
{
parent::__construct($connection);
$this->helper = new OracleAutoIncrementHelper($connection);
$this->comment = new Comment($connection);
$this->ctxDdlPreferences = new OraclePreferences($connection);
}

/**
Expand All @@ -37,6 +43,8 @@ public function create($table, Closure $callback): void

$callback($blueprint);

$this->ctxDdlPreferences->createPreferences($blueprint);

$this->build($blueprint);

$this->comment->setComments($blueprint);
Expand Down Expand Up @@ -84,6 +92,7 @@ public function table($table, Closure $callback): void
public function drop($table): void
{
$this->helper->dropAutoIncrementObjects($table);
$this->ctxDdlPreferences->dropPreferencesByTable($table);
parent::drop($table);
}

Expand All @@ -92,6 +101,7 @@ public function drop($table): void
*/
public function dropAllTables(): void
{
$this->ctxDdlPreferences->dropAllPreferences();
$this->connection->statement($this->grammar->compileDropAllTables());
}

Expand All @@ -103,6 +113,7 @@ public function dropAllTables(): void
public function dropIfExists($table): void
{
$this->helper->dropAutoIncrementObjects($table);
$this->ctxDdlPreferences->dropPreferencesByTable($table);
parent::dropIfExists($table);
}

Expand Down
151 changes: 151 additions & 0 deletions src/Oci8/Schema/OraclePreferences.php
Original file line number Diff line number Diff line change
@@ -0,0 +1,151 @@
<?php

namespace Yajra\Oci8\Schema;

use Illuminate\Database\Connection;
use Illuminate\Database\Schema\Blueprint;

/**
* @see https://docs.oracle.com/en/database/oracle/oracle-database/19/ccref/CTX_DDL-package.html#GUID-0F7C39E8-E44A-421C-B40D-3B3578B507E9
*/
class OraclePreferences
{
/**
* @var \Illuminate\Database\Connection
*/
protected $connection;

/**
* @var array
*/
protected array $columns = [];

/**
* @var array
*/
protected array $preferenceName = [];

/**
* Constructor method.
*
* @return void
*/
public function __construct(Connection $connection)
{
$this->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);
}
}
43 changes: 43 additions & 0 deletions tests/Database/Oci8QueryBuilderTest.php
Original file line number Diff line number Diff line change
Expand Up @@ -705,6 +705,49 @@ public function test_array_where_column()
$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 test_unions()
{
$builder = $this->getBuilder();
Expand Down
Loading

0 comments on commit 20a5624

Please sign in to comment.