Skip to content

Commit 4ae03f5

Browse files
committed
feat: pg18 temporal indexes (references #117)
1 parent 69de64b commit 4ae03f5

File tree

8 files changed

+224
-27
lines changed

8 files changed

+224
-27
lines changed

README.md

Lines changed: 63 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -49,6 +49,7 @@ The minimal breaking changes of the past years are listed in the [breaking chang
4949
- [Storage Parameters](#storage-parameters-index)
5050
- [Functional Indexes / Column Options](#functional-indexes--column-options)
5151
- [Fulltext Indexes](#fulltext-indexes)
52+
- [Temporal Indexes](#temporal-indexes)
5253
- [Domain Types](#domain-types)
5354
- [Table Options](#table-options)
5455
- [Unlogged](#unlogged)
@@ -587,6 +588,68 @@ Schema::table('book', function (Blueprint $table) {
587588
});
588589
```
589590

591+
#### Temporal Indexes
592+
593+
Imagine you've built a shopping system and one day a customer complains that his order was sent to their old address, which is hundreds of miles away from the current one.
594+
The current data in the database also shows you the current address - so you made a mistake?
595+
But how was the address when the order was shipped?
596+
Have you logged the change in an audit table?
597+
Happy for you if you did, but querying the data is complicated...
598+
599+
So PostgreSQL 18 added support for temporal database features:
600+
You can now version control your data with primary keys, unique keys and foreign keys that are only valid for a specific point in time:
601+
602+
```php
603+
use Tpetry\PostgresqlEnhanced\Schema\Blueprint;
604+
use Tpetry\PostgresqlEnhanced\Support\Facades\Schema;
605+
606+
Schema::createExtensionIfNotExists('btree_gist');
607+
Schema::create('addresses', function (Blueprint $table) {
608+
$table->uuid('id');
609+
$table->timestampTzRange('valid');
610+
// ...
611+
612+
$table->primary(['id', 'valid WITHOUT OVERLAPS']);
613+
});
614+
Schema::create('orders', function (Blueprint $table) {
615+
$table->uuid('id');
616+
$table->uuid('address_id');
617+
$table->text('reference_nr');
618+
$table->timestampTzRange('valid');
619+
// ...
620+
621+
$table->primary(['id', 'valid WITHOUT OVERLAPS']);
622+
$table->unique(['reference_nr', 'valid WITHOUT OVERLAPS']);
623+
$table->foreign(['address_id', 'PERIOD valid'])->references(['id', 'PERIOD valid'])->on('addresses');
624+
});
625+
626+
Address::insert([
627+
[
628+
'id' => '7f8f1ee1-63fc-4472-8950-034aeb75da38',
629+
'valid' => '["2000-01-01 00:00:00+00","2025-01-01 00:00:00+00")',
630+
],
631+
[
632+
'id' => '7f8f1ee1-63fc-4472-8950-034aeb75da38',
633+
'valid' => '["2025-01-01 00:00:00+00",)',
634+
],
635+
]);
636+
Order::insert([
637+
'id' => '93c7d2a9-41d9-4fba-9943-7c97c4420d59',
638+
'address_id' => '7f8f1ee1-63fc-4472-8950-034aeb75da38',
639+
'reference_nr' => '1234567890',
640+
'valid' => '["2025-10-17 10:46:34+00",)',
641+
]);
642+
643+
Order::query()
644+
->join('addresses', 'addresses.id', 'orders.address_id')
645+
->where('addresses.valid', '@>', new Expression('LOWER(orders.valid)'))
646+
->whereKey('93c7d2a9-41d9-4fba-9943-7c97c4420d59');
647+
```
648+
649+
> [!NOTE]
650+
> There is no Eloquent implementation for temporal features yet.
651+
> But a full implementation would replace Laravel's soft-deletes implementation.
652+
590653
### Domain Types
591654

592655
A relational database like PostgreSQL provides a lot of data types you can choose from.

src/Schema/BlueprintIndex.php

Lines changed: 6 additions & 7 deletions
Original file line numberDiff line numberDiff line change
@@ -88,10 +88,6 @@ public function uniqueIndex($columns, ?string $name = null, ?string $algorithm =
8888
*/
8989
protected function createIndexName($type, array $columns): string
9090
{
91-
if ('unique' === $type) {
92-
return parent::createIndexName($type, $columns);
93-
}
94-
9591
$columns = array_map(function (string $column): string {
9692
// When the column has a structure like '(.+).*' it's an functional index. But it's not
9793
// easily possible to extract column names from a functional expression so the developer
@@ -112,9 +108,12 @@ protected function createIndexName($type, array $columns): string
112108
}
113109

114110
// When index parameters are defined the space in the sql grammar is the separation character
115-
// of the column and all params. So in case a space is available only the part before the first
116-
// space character is declaring the column and will be used.
117-
return Str::before($column, ' ');
111+
// of the column and all params. So in case a space is available, special index behavior is
112+
// defined and the real column name must be extracted.
113+
return match (str_starts_with(strtolower($column), 'period ')) {
114+
true => Str::after($column, ' '),
115+
false => Str::before($column, ' '),
116+
};
118117
}, $columns);
119118

120119
return parent::createIndexName($type, $columns);

src/Schema/Grammars/GrammarForeignKey.php

Lines changed: 19 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -4,7 +4,10 @@
44

55
namespace Tpetry\PostgresqlEnhanced\Schema\Grammars;
66

7+
use Illuminate\Contracts\Database\Query\Expression as ExpressionContract;
8+
use Illuminate\Database\Query\Expression;
79
use Illuminate\Database\Schema\Blueprint;
10+
use Illuminate\Support\Arr;
811
use Illuminate\Support\Fluent;
912

1013
trait GrammarForeignKey
@@ -14,6 +17,22 @@ trait GrammarForeignKey
1417
*/
1518
public function compileForeign(Blueprint $blueprint, Fluent $command): string
1619
{
20+
foreach (['columns', 'references'] as $columnsKey) {
21+
$command[$columnsKey] = array_map(function (string|Expression|ExpressionContract $column) {
22+
if ($this->isExpression($column)) {
23+
return $column;
24+
}
25+
26+
if (str_starts_with(strtolower($column), 'period ')) {
27+
$column = trim(substr($column, 7));
28+
29+
return new Expression("PERIOD {$this->wrap($column)}");
30+
}
31+
32+
return $column;
33+
}, Arr::wrap($command[$columnsKey]));
34+
}
35+
1736
$sql = parent::compileForeign($blueprint, $command);
1837
if ($command->get('notEnforced')) {
1938
$sql .= ' not enforced';

src/Schema/Grammars/GrammarIndex.php

Lines changed: 34 additions & 4 deletions
Original file line numberDiff line numberDiff line change
@@ -4,6 +4,8 @@
44

55
namespace Tpetry\PostgresqlEnhanced\Schema\Grammars;
66

7+
use Illuminate\Contracts\Database\Query\Expression as ExpressionContract;
8+
use Illuminate\Database\Query\Expression;
79
use Illuminate\Database\Schema\Blueprint;
810
use Illuminate\Support\Fluent;
911
use Tpetry\PostgresqlEnhanced\Support\Helpers\MigrationIndex;
@@ -73,15 +75,23 @@ public function compileFulltext(Blueprint $blueprint, Fluent $command): string
7375
{
7476
$command['algorithm'] ??= 'gin';
7577

76-
return (new MigrationIndex())->compileCommand($this, $blueprint->getTable(), $command, false);
78+
return (new MigrationIndex())->compileCommand($this, $blueprint->getTable(), $command, 'index');
7779
}
7880

7981
/**
8082
* Compile a plain index key command.
8183
*/
8284
public function compileIndex(Blueprint $blueprint, Fluent $command): string
8385
{
84-
return (new MigrationIndex())->compileCommand($this, $blueprint->getTable(), $command, false);
86+
return (new MigrationIndex())->compileCommand($this, $blueprint->getTable(), $command, 'index');
87+
}
88+
89+
/**
90+
* Compile a primary key command.
91+
*/
92+
public function compilePrimary(Blueprint $blueprint, Fluent $command): string
93+
{
94+
return (new MigrationIndex())->compileCommand($this, $blueprint->getTable(), $command, 'primary');
8595
}
8696

8797
/**
@@ -91,14 +101,34 @@ public function compileSpatialIndex(Blueprint $blueprint, Fluent $command): stri
91101
{
92102
$command['algorithm'] = 'gist';
93103

94-
return (new MigrationIndex())->compileCommand($this, $blueprint->getTable(), $command, false);
104+
return (new MigrationIndex())->compileCommand($this, $blueprint->getTable(), $command, 'index');
105+
}
106+
107+
/**
108+
* Compile a unique key command.
109+
*
110+
* @return string|string[]
111+
*/
112+
public function compileUnique(Blueprint $blueprint, Fluent $command): mixed
113+
{
114+
$command['columns'] = array_map(function (string|Expression|ExpressionContract $column) {
115+
if ($this->isExpression($column)) {
116+
return $column;
117+
}
118+
119+
$parts = explode(' ', $column, 2);
120+
121+
return new Expression(trim(\sprintf('%s %s', $this->wrap($parts[0]), $parts[1] ?? '')));
122+
}, $command['columns']);
123+
124+
return parent::compileUnique($blueprint, $command);
95125
}
96126

97127
/**
98128
* Compile a unique key command.
99129
*/
100130
public function compileUnique2(Blueprint $blueprint, Fluent $command): string
101131
{
102-
return (new MigrationIndex())->compileCommand($this, $blueprint->getTable(), $command, true);
132+
return (new MigrationIndex())->compileCommand($this, $blueprint->getTable(), $command, 'unique');
103133
}
104134
}

src/Schema/Timescale/CaggBlueprint.php

Lines changed: 1 addition & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -83,7 +83,7 @@ public function index(string|array $columns, ?string $name = null, ?string $algo
8383
/** @var \Tpetry\PostgresqlEnhanced\Schema\IndexDefinition $fluent */
8484
$fluent = $migration->createCommand('index', $name ?: $migration->createName('index', '', $this->table, $columns), $columns, $algorithm);
8585

86-
$this->commands[] = fn (Connection $connection, Grammar $grammar) => [(new MigrationIndex())->compileCommand($grammar, $this->table, $fluent, false)];
86+
$this->commands[] = fn (Connection $connection, Grammar $grammar) => [(new MigrationIndex())->compileCommand($grammar, $this->table, $fluent, 'index')];
8787

8888
return $fluent;
8989
}

src/Support/Helpers/MigrationIndex.php

Lines changed: 26 additions & 15 deletions
Original file line numberDiff line numberDiff line change
@@ -18,7 +18,10 @@
1818
*/
1919
class MigrationIndex
2020
{
21-
public function compileCommand(Grammar $grammar, string $table, Fluent $command, bool $unique): string
21+
/**
22+
* @param 'index'|'primary'|'unique' $type
23+
*/
24+
public function compileCommand(Grammar $grammar, string $table, Fluent $command, string $type): string
2225
{
2326
// If the index is partial index using a closure a dummy query builder is provided to the closure. The query is
2427
// then transformed to a static query and the select part is removed to only keep the condition.
@@ -72,20 +75,27 @@ public function compileCommand(Grammar $grammar, string $table, Fluent $command,
7275
$columns = ['('.implode(' || ', $columns).')'];
7376
}
7477

75-
$index = [
76-
$unique ? 'create unique index' : 'create index',
77-
$command['concurrently'] ? 'concurrently' : null,
78-
$command['ifNotExists'] ? 'if not exists' : null,
79-
$grammar->wrap($command['index']),
80-
'on',
81-
$grammar->wrapTable($table),
82-
$command['algorithm'] ? "using {$command['algorithm']}" : null,
83-
'('.implode(', ', $columns).')',
84-
$command['include'] ? 'include ('.implode(',', $grammar->wrapArray(Arr::wrap($command['include']))).')' : null,
85-
$command['nullsNotDistinct'] ? 'nulls not distinct' : null,
86-
$command['with'] ? "with ({$command['with']})" : null,
87-
$command['where'] ? "where {$command['where']}" : null,
88-
];
78+
$index = match ($type) {
79+
'index', 'unique' => [
80+
'unique' === $type ? 'create unique index' : 'create index',
81+
$command['concurrently'] ? 'concurrently' : null,
82+
$command['ifNotExists'] ? 'if not exists' : null,
83+
$grammar->wrap($command['index']),
84+
'on',
85+
$grammar->wrapTable($table),
86+
$command['algorithm'] ? "using {$command['algorithm']}" : null,
87+
'('.implode(', ', $columns).')',
88+
$command['include'] ? 'include ('.implode(',', $grammar->wrapArray(Arr::wrap($command['include']))).')' : null,
89+
$command['nullsNotDistinct'] ? 'nulls not distinct' : null,
90+
$command['with'] ? "with ({$command['with']})" : null,
91+
$command['where'] ? "where {$command['where']}" : null,
92+
],
93+
'primary' => [
94+
'alter table',
95+
$grammar->wrapTable($table),
96+
'add primary key ('.implode(', ', $columns).')',
97+
],
98+
};
8999
$sql = implode(' ', array_filter($index, fn (?string $part) => filled($part)));
90100

91101
return $sql;
@@ -104,6 +114,7 @@ public function createName(string $type, string $prefix, string $table, array $c
104114
true => substr_replace("{$table}.{$prefix}", strrpos($table, '.'), 1),
105115
false => $prefix.$table,
106116
};
117+
$columns = array_map(fn (string $column) => Str::before($column, ' '), $columns);
107118

108119
$index = strtolower($table.'_'.implode('_', $columns).'_'.$type);
109120

tests/Migration/ForeignKeyTest.php

Lines changed: 18 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -44,4 +44,22 @@ public function testNotEnforcedTrue(): void
4444
});
4545
$this->assertEquals(['alter table "test_861910" add constraint "test_861910_col_422395_foreign" foreign key ("col_422395") references "test_940615" ("col_422395") not enforced'], array_column($queries, 'query'));
4646
}
47+
48+
public function testPeriod(): void
49+
{
50+
if (Comparator::lessThan($this->getConnection()->serverVersion(), '18')) {
51+
$this->markTestSkipped('Foreign key PERIOD is first supported with PostgreSQL 18.');
52+
}
53+
54+
Schema::createExtensionIfNotExists('btree_gist');
55+
$this->getConnection()->statement('CREATE TABLE test_668671 (col_975277 bigint, valid tstzrange, PRIMARY KEY (col_975277, valid WITHOUT OVERLAPS))');
56+
$this->getConnection()->statement('CREATE TABLE test_178855 (col_975277 bigint, valid tstzrange, PRIMARY KEY (col_975277, valid WITHOUT OVERLAPS))');
57+
58+
$queries = $this->withQueryLog(function (): void {
59+
Schema::table('test_178855', function (Blueprint $table): void {
60+
$table->foreign(['col_975277', 'PERIOD valid'])->references(['col_975277', 'PERIOD valid'])->on('test_668671');
61+
});
62+
});
63+
$this->assertEquals(['alter table "test_178855" add constraint "test_178855_col_975277_valid_foreign" foreign key ("col_975277", PERIOD "valid") references "test_668671" ("col_975277", PERIOD "valid")'], array_column($queries, 'query'));
64+
}
4765
}

tests/Migration/IndexOptionsTest.php

Lines changed: 57 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -695,6 +695,63 @@ public function testWithIndexByName(): void
695695
$this->assertEquals(['create index "index_477176" on "test_533609" ("col_889546") with (fillfactor = 80)'], array_column($queries, 'query'));
696696
}
697697

698+
public function testWithoutOverlapsPrimary(): void
699+
{
700+
if (Comparator::lessThan($this->getConnection()->serverVersion(), '18')) {
701+
$this->markTestSkipped('WITHOUT OVERLAPS is first supported with PostgreSQL 18.');
702+
}
703+
704+
Schema::createExtensionIfNotExists('btree_gist');
705+
Schema::create('test_897145', function (Blueprint $table): void {
706+
$table->string('col_301428');
707+
$table->timestampTzRange('col_734356');
708+
});
709+
$queries = $this->withQueryLog(function (): void {
710+
Schema::table('test_897145', function (Blueprint $table): void {
711+
$table->primary(['col_301428', 'col_734356 WITHOUT OVERLAPS']);
712+
});
713+
});
714+
$this->assertEquals(['alter table "test_897145" add primary key ("col_301428", "col_734356" WITHOUT OVERLAPS)'], array_column($queries, 'query'));
715+
}
716+
717+
public function testWithoutOverlapsUniqueByColumn(): void
718+
{
719+
if (Comparator::lessThan($this->getConnection()->serverVersion(), '18')) {
720+
$this->markTestSkipped('WITHOUT OVERLAPS is first supported with PostgreSQL 18.');
721+
}
722+
723+
Schema::createExtensionIfNotExists('btree_gist');
724+
Schema::create('test_849793', function (Blueprint $table): void {
725+
$table->string('col_376999');
726+
$table->timestampTzRange('col_513975');
727+
});
728+
$queries = $this->withQueryLog(function (): void {
729+
Schema::table('test_849793', function (Blueprint $table): void {
730+
$table->unique(['col_376999', 'col_513975 WITHOUT OVERLAPS']);
731+
});
732+
});
733+
$this->assertEquals(['alter table "test_849793" add constraint "test_849793_col_376999_col_513975_unique" unique ("col_376999", "col_513975" WITHOUT OVERLAPS)'], array_column($queries, 'query'));
734+
}
735+
736+
public function testWithoutOverlapsUniqueByName(): void
737+
{
738+
if (Comparator::lessThan($this->getConnection()->serverVersion(), '18')) {
739+
$this->markTestSkipped('WITHOUT OVERLAPS is first supported with PostgreSQL 18.');
740+
}
741+
742+
Schema::createExtensionIfNotExists('btree_gist');
743+
Schema::create('test_224202', function (Blueprint $table): void {
744+
$table->string('col_405091');
745+
$table->timestampTzRange('col_427625');
746+
});
747+
$queries = $this->withQueryLog(function (): void {
748+
Schema::table('test_224202', function (Blueprint $table): void {
749+
$table->unique(['col_405091', 'col_427625 WITHOUT OVERLAPS'], 'index_142173');
750+
});
751+
});
752+
$this->assertEquals(['alter table "test_224202" add constraint "index_142173" unique ("col_405091", "col_427625" WITHOUT OVERLAPS)'], array_column($queries, 'query'));
753+
}
754+
698755
public function testWithRawIndex(): void
699756
{
700757
if (Comparator::lessThan($this->app->version(), '7.7.0')) {

0 commit comments

Comments
 (0)