diff --git a/CHANGELOG.md b/CHANGELOG.md index b64e1ed..eb234d5 100644 --- a/CHANGELOG.md +++ b/CHANGELOG.md @@ -4,6 +4,10 @@ All notable changes to this project will be documented in this file. The format is based on [Keep a Changelog](https://keepachangelog.com/en/1.0.0/), and this project adheres to [Semantic Versioning](https://semver.org/spec/v2.0.0.html). +## [0.7.0] - 2021-12-16 +### Added +* PostgreSQL specific explain output on Query\Builder instances + ## [0.6.1] - 2021-10-28 ### Fixed - Zero Downtime Migration support for Laravel 6.x and 7.x diff --git a/README.md b/README.md index e7aa04b..1504383 100644 --- a/README.md +++ b/README.md @@ -23,6 +23,7 @@ composer require tpetry/laravel-postgresql-enhanced - [Zero Downtime Migration](#zero-downtime-migration) - [Extensions](#extensions) - [Views](#views) + - [Explain](#explain) - [Indexes](#indexes) - [Partial Indexes](#partial-indexes) - [Include Columns](#include-columns) @@ -161,6 +162,48 @@ Schema::dropView('myview1', 'myview2'); Schema::dropViewIfExists('myview1', 'myview2'); ``` +### Explain +Laravel has the ability to get the database query plan for any query you are building. Just calling `explain()` on the query will get a collection with the query plan. + +This behaviour has been extended to be more PostgreSQL specific. There are multiple (optional) parameters for the [explain statement](https://www.postgresql.org/docs/current/sql-explain.html), different for every version. The enhanced PostgreSQL driver will automatically activate all options available for your PostgreSQL version. + +```php +DB::table('migrations')->where('batch', 1)->explain()->dd(); + +// Output: +// array:1 [ +// 0 => """ +// Seq Scan on public.migrations (cost=0.00..11.75 rows=1 width=524)\n +// Output: id, migration, batch\n +// Filter: (migrations.batch = 1)\n +// Settings: search_path = 'public'\n +// Planning Time: 0.370 ms +// """ +//] +``` + +Additionally, you can also get the query plan with executing the query. The query plan will be extended by valuable runtime information like per-operation timing and buffer read/write statistics: + +```php +DB::table('migrations')->where('batch', 1)->explain(analyze:true)->dd(); + +// Output: +// array:1 [ +// 0 => """ +// Seq Scan on public.migrations (cost=0.00..11.75 rows=1 width=524) (actual time=0.014..0.031 rows=1 loops=1)\n +// Output: id, migration, batch\n +// Filter: (migrations.batch = 1)\n +// Buffers: shared hit=1\n +// Settings: search_path = 'public'\n +// Planning:\n +// Buffers: shared hit=61\n +// Planning Time: 0.282 ms\n +// Execution Time: 0.100 ms +// """ +//] +``` +**NOTE: The PostgreSQL-specific query plan is currently limited to `Query\Builder` instances, for `Eloquent\Builder` instances [PR #40075](https://github.com/laravel/framework/pull/40075) needs to be merged to Laravel or you have to use `$query->toBase()` for transforming an eloquent query builder to a base query builder.** + ### Indexes #### Unique Indexes diff --git a/src/PostgresEnhancedConnection.php b/src/PostgresEnhancedConnection.php index ad71a45..0e3f29b 100644 --- a/src/PostgresEnhancedConnection.php +++ b/src/PostgresEnhancedConnection.php @@ -10,7 +10,8 @@ use Illuminate\Database\QueryException; use Illuminate\Support\Str; use Throwable; -use Tpetry\PostgresqlEnhanced\Schema\Builder; +use Tpetry\PostgresqlEnhanced\Query\Builder as QueryBuilder; +use Tpetry\PostgresqlEnhanced\Schema\Builder as SchemaBuilder; use Tpetry\PostgresqlEnhanced\Schema\Grammars\Grammar; use Tpetry\PostgresqlEnhanced\Support\Helpers\ZeroDowntimeMigrationSupervisor; @@ -21,13 +22,21 @@ class PostgresEnhancedConnection extends PostgresConnection /** * Get a schema builder instance for the connection. */ - public function getSchemaBuilder(): Builder + public function getSchemaBuilder(): SchemaBuilder { if (null === $this->schemaGrammar) { $this->useDefaultSchemaGrammar(); } - return new Builder($this); + return new SchemaBuilder($this); + } + + /** + * Get a new query builder instance. + */ + public function query(): QueryBuilder + { + return new QueryBuilder($this, $this->getQueryGrammar(), $this->getPostProcessor()); } /** diff --git a/src/Query/Builder.php b/src/Query/Builder.php new file mode 100644 index 0000000..bfa2208 --- /dev/null +++ b/src/Query/Builder.php @@ -0,0 +1,34 @@ +getConnection()->selectOne('SHOW server_version')->server_version; + $options = match (true) { + $analyze && version_compare($version, '13') >= 0 => 'ANALYZE TRUE, BUFFERS TRUE, SETTINGS TRUE, VERBOSE TRUE, WAL TRUE', + $analyze && version_compare($version, '12') >= 0 => 'ANALYZE TRUE, BUFFERS TRUE, SETTINGS TRUE, VERBOSE TRUE', + $analyze => 'ANALYZE TRUE, BUFFERS TRUE, VERBOSE TRUE', + version_compare($version, '12') >= 0 => 'SETTINGS TRUE, SUMMARY TRUE, VERBOSE TRUE', + default => 'SUMMARY TRUE, VERBOSE TRUE', + }; + + return (new Collection($this->getConnection()->select("EXPLAIN ({$options}) {$this->toSql()}", $this->getBindings()))) + ->map(fn ($row) => Arr::first($row)) + ->reduce(function (?Collection $carry, string $item) { + if (null === $carry) { + return new Collection([$item]); + } + + return new Collection(["{$carry[0]}\n{$item}"]); + }); + } +}