From 4ba53dca7d278518da90a10c64659cc6ec9293eb Mon Sep 17 00:00:00 2001 From: jbranchaud Date: Mon, 7 Apr 2025 17:52:13 -0500 Subject: [PATCH] Add Create And Execute SQL Statements With \gexec as a Postgres TIL --- README.md | 3 +- ...e-and-execute-sql-statements-with-gexec.md | 58 +++++++++++++++++++ 2 files changed, 60 insertions(+), 1 deletion(-) create mode 100644 postgres/create-and-execute-sql-statements-with-gexec.md diff --git a/README.md b/README.md index f3b514c..7d59325 100644 --- a/README.md +++ b/README.md @@ -10,7 +10,7 @@ pairing with smart people at Hashrocket. For a steady stream of TILs, [sign up for my newsletter](https://crafty-builder-6996.ck.page/e169c61186). -_1634 TILs and counting..._ +_1635 TILs and counting..._ See some of the other learning resources I work on: - [Ruby Operator Lookup](https://www.visualmode.dev/ruby-operators) @@ -820,6 +820,7 @@ If you've learned something here, support my efforts writing daily TILs by - [Create A Table From The Structure Of Another](postgres/create-a-table-from-the-structure-of-another.md) - [Create An Index Across Two Columns](postgres/create-an-index-across-two-columns.md) - [Create An Index Without Locking The Table](postgres/create-an-index-without-locking-the-table.md) +- [Create And Execute SQL Statements With \gexec](postgres/create-and-execute-sql-statements-with-gexec.md) - [Create Database Uses Template1](postgres/create-database-uses-template1.md) - [Create hstore From Two Arrays](postgres/create-hstore-from-two-arrays.md) - [Create Table Adds A Data Type](postgres/create-table-adds-a-data-type.md) diff --git a/postgres/create-and-execute-sql-statements-with-gexec.md b/postgres/create-and-execute-sql-statements-with-gexec.md new file mode 100644 index 0000000..0aad6a9 --- /dev/null +++ b/postgres/create-and-execute-sql-statements-with-gexec.md @@ -0,0 +1,58 @@ +# Create And Execute SQL Statements With \gexec + +The [`\gexec` +meta-command](https://www.postgresql.org/docs/current/app-psql.html#APP-PSQL-META-COMMAND-GEXEC) +is a variation of the [`\g` +meta-command](https://www.postgresql.org/docs/current/app-psql.html#APP-PSQL-META-COMMAND-G), +both of which can be used in a `psql` session. Whereas the `\g` command sends +the current query in the buffer to the PostgreSQL server for execution, the +`\gexec` command first sends the query to the server for execution and then +executes each row of the result as its own SQL statement. + +This is both a bit absurd and powerful. And a bit unnecessary considering all +of the scripting capabilities with anything from bash to any language with a +SQL client library. + +Nevertheless, let's take a look at a contrived example of how it works. Here, +we have a SQL statement that does some string concatenation based off values in +an array. This results in three separate `create schema` statements. + +```sql +> select + 'create schema if not exists schema_' || letter || ';' + from unnest(array['a', 'b', 'c']) as letter + \gexec + +CREATE SCHEMA +CREATE SCHEMA +CREATE SCHEMA + +> \dn + List of schemas + Name | Owner +----------+------------------- + public | pg_database_owner + schema_a | postgres + schema_b | postgres + schema_c | postgres +(4 rows) +``` + +Three new schemas get created which we can inspect with `\dn`. + +Notice, if we simply execute the primary statement, we can see the intermediate +result that `\gexec` will subsequently execute. + +```sql +> select + 'create schema if not exists schema_' || letter || ';' + from unnest(array['a', 'b', 'c']) as letter + \g + + ?column? +--------------------------------------- + create schema if not exists schema_a; + create schema if not exists schema_b; + create schema if not exists schema_c; +(3 rows) +```