Skip to content

Commit 2a91796

Browse files
committed
readme
1 parent 3d142be commit 2a91796

File tree

5 files changed

+216
-12
lines changed

5 files changed

+216
-12
lines changed

packages/ast/Makefile

Lines changed: 1 addition & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -1,5 +1,5 @@
11
EXTENSION = ast
2-
DATA = sql/ast--0.0.1.sql
2+
DATA = sql/ast--13.0.1.sql
33

44
PG_CONFIG = pg_config
55
PGXS := $(shell $(PG_CONFIG) --pgxs)

packages/ast/ast.control

Lines changed: 1 addition & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -1,6 +1,6 @@
11
# ast extension
22
comment = 'ast extension'
3-
default_version = '0.0.1'
3+
default_version = '13.0.1'
44
module_pathname = '$libdir/ast'
55
requires = 'plpgsql,uuid-ossp'
66
relocatable = false

packages/ast/package.json

Lines changed: 1 addition & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -51,4 +51,4 @@
5151
"__fixtures__"
5252
]
5353
}
54-
}
54+
}
File renamed without changes.

readme.md

Lines changed: 213 additions & 9 deletions
Original file line numberDiff line numberDiff line change
@@ -10,12 +10,19 @@ For dynamic SQL, string concatenation can be problematic, and AST trees are the
1010

1111
Written entirely in plpgsql and can be installed anywhere, even in managed RDBMS environments that don't support untrusted extensions.
1212

13-
## Schemas of interest
13+
## Areas of interest
14+
15+
### schemas
1416

1517
- `deparser` contains the deparser [(the `deparse()` function)](packages/ast/deploy/schemas/deparser/procedures/deparse.sql) — where the magic happens ✨
1618
- `ast` contains [tools for building AST trees](packages/ast/deploy/schemas/ast/procedures/types.sql)
1719
- `ast_helpers` contains [Helpers for higher level AST trees, like `create_table`](packages/ast/deploy/schemas/ast_helpers/procedures/helpers.sql)
1820

21+
### extension
22+
23+
While the project uses [sqitch](https://sqitch.org/), we've bundled it into a single file and extension using [launchql/cli](https://github.com/launchql/launchql)
24+
25+
- the extension lives in [packages/ast/sql](packages/ast/sql)
1926
## Usage
2027

2128
Use the `deparser.deparse()` function to deparse Postgres AST trees, in SQL:
@@ -62,6 +69,25 @@ produces
6269
SELECT mt.my_field FROM my_schema_name.my_table_name AS mt WHERE mt.id = 2
6370
```
6471

72+
#### create table
73+
74+
```sql
75+
select deparser.deparse(
76+
ast_helpers.create_table(
77+
v_schema_name := 'my_schema_name',
78+
v_table_name := 'my_table_name'
79+
)
80+
);
81+
```
82+
83+
produces
84+
85+
```sql
86+
CREATE TABLE my_schema_name.my_table_name (
87+
88+
);
89+
```
90+
6591
#### alter table add column
6692

6793
```sql
@@ -85,18 +111,23 @@ ADD
85111
COLUMN mycolumn pg_catalog.Geometry(Polygon, 4326);
86112
```
87113

88-
#### drop function
114+
#### rename column
89115

90116
```sql
91-
SELECT deparser.deparse(ast_helpers.drop_function(
92-
v_schema_name := 'schema',
93-
v_function_name := 'name'
94-
));
117+
select deparser.expression(
118+
ast_helpers.alter_table_rename_column(
119+
v_schema_name := 'myschema',
120+
v_table_name := 'mytable',
121+
v_old_column_name := 'my-column1',
122+
v_new_column_name := 'mycolumn2'
123+
)
124+
);
95125
```
96-
produces
126+
127+
produces
97128

98129
```sql
99-
DROP FUNCTION schema.name;
130+
ALTER TABLE myschema.mytable RENAME COLUMN "my-column1" TO mycolumn2;
100131
```
101132

102133
#### alter table set column data type
@@ -121,6 +152,53 @@ ALTER TABLE
121152
ALTER COLUMN
122153
mycolumn1 TYPE mycustomtype USING mycolumn1::mycustomtype;
123154
```
155+
#### create index
156+
157+
```sql
158+
select deparser.deparse(
159+
ast_helpers.create_index(
160+
v_index_name := 'v_index_name',
161+
v_schema_name := 'v_schema_name',
162+
v_table_name := 'v_table_name',
163+
v_fields := '{a,b,c}',
164+
v_include_fields := '{a,b}',
165+
v_unique := TRUE,
166+
v_accessMethod := 'GIST'
167+
)
168+
);
169+
```
170+
171+
produces
172+
173+
```sql
174+
CREATE UNIQUE INDEX v_index_name ON v_schema_name.v_table_name USING GIST (a, b, c) INCLUDE (a, b);
175+
```
176+
177+
### add check constraint
178+
179+
```sql
180+
select deparser.expression(
181+
ast_helpers.alter_table_add_check_constraint(
182+
v_schema_name := 'schema_name',
183+
v_table_name := 'table_name',
184+
v_constraint_name := 'constraint_name',
185+
v_constraint_expr := ast_helpers.matches(
186+
v_lexpr := ast.column_ref(
187+
v_fields := to_jsonb(ARRAY[
188+
ast.string('email')
189+
])
190+
),
191+
v_regexp := '^[A-Za-z0-9._%-]+@[A-Za-z0-9.-]+[.][A-Za-z]+$'
192+
)
193+
)
194+
);
195+
```
196+
197+
produces
198+
199+
```sql
200+
ALTER TABLE schema_name.table_name ADD CONSTRAINT constraint_name CHECK (email ~* '^[A-Za-z0-9._%-]+@[A-Za-z0-9.-]+[.][A-Za-z]+$');
201+
```
124202

125203
#### create function
126204

@@ -177,6 +255,20 @@ CREATE FUNCTION schema.name (
177255
$LQLCODEZ$ LANGUAGE plpgsql VOLATILE;
178256
```
179257

258+
#### drop function
259+
260+
```sql
261+
SELECT deparser.deparse(ast_helpers.drop_function(
262+
v_schema_name := 'schema',
263+
v_function_name := 'name'
264+
));
265+
```
266+
produces
267+
268+
```sql
269+
DROP FUNCTION schema.name;
270+
```
271+
180272
#### table grant
181273

182274
```sql
@@ -307,6 +399,89 @@ ALTER POLICY mypolicy
307399
);
308400
```
309401

402+
#### create trigger
403+
404+
```sql
405+
select
406+
deparser.deparse(
407+
ast_helpers.create_trigger(
408+
v_trigger_name := 'v_trigger_name',
409+
v_schema_name := 'v_schema_name',
410+
v_table_name := 'v_table_name',
411+
v_trigger_fn_schema := 'v_trigger_fn_schema',
412+
v_trigger_fn_name := 'v_trigger_fn_name',
413+
v_whenClause := ast.a_expr(
414+
v_kind := 'AEXPR_DISTINCT',
415+
v_lexpr := ast.column_ref(
416+
to_jsonb(ARRAY [ ast.string('old'),ast.string('field-b') ])
417+
),
418+
v_name := to_jsonb(ARRAY [ast.string('=')]),
419+
v_rexpr := ast.column_ref(
420+
to_jsonb(ARRAY [ ast.string('new'),ast.string('field-b') ])
421+
)
422+
),
423+
v_params := NULL,
424+
v_timing := 2,
425+
v_events := 16
426+
)
427+
);
428+
```
429+
430+
produces
431+
432+
```sql
433+
CREATE TRIGGER v_trigger_name
434+
BEFORE UPDATE ON v_schema_name.v_table_name
435+
FOR EACH ROW
436+
WHEN (OLD."field-b" IS DISTINCT FROM NEW."field-b")
437+
EXECUTE PROCEDURE v_trigger_fn_schema.v_trigger_fn_name ( );
438+
```
439+
440+
### trigger distinct fields
441+
442+
```sql
443+
select deparser.deparse(
444+
ast_helpers.create_trigger_distinct_fields(
445+
v_trigger_name := 'my-trigger',
446+
v_schema_name := 'my-schema',
447+
v_table_name := 'my-table',
448+
v_trigger_fn_schema := 'my-tg-fn-schema',
449+
v_trigger_fn_name := 'my-tg-fn',
450+
v_fields := ARRAY['name', 'description']::text[],
451+
v_timing := 2,
452+
v_events := 4 | 16)
453+
)
454+
```
455+
456+
produces
457+
458+
```sql
459+
CREATE TRIGGER "my-trigger"
460+
BEFORE INSERT OR UPDATE ON "my-schema"."my-table"
461+
FOR EACH ROW
462+
WHEN (OLD.name IS DISTINCT FROM NEW.name OR OLD.description IS DISTINCT FROM NEW.description)
463+
EXECUTE PROCEDURE "my-tg-fn-schema"."my-tg-fn" ( );
464+
```
465+
466+
#### fixtures
467+
468+
```sql
469+
select deparser.deparse(
470+
ast_helpers.create_fixture(
471+
v_schema := 'myschema',
472+
v_table := 'mytable',
473+
v_cols := '{a,b,c,d}',
474+
v_values := '[[{"type":"int","value":1},{"type":"text","value":"textme"},{"type":"float","value":1.3},{"type":"bool","value":true}],[{"type":"int","value":2},{"type":"text","value":"yolo"},{"type":"float","value":1.3},{"type":"bool","value":false}]]'
475+
)
476+
);
477+
```
478+
479+
produces
480+
481+
```sql
482+
INSERT INTO myschema.mytable (a, b, c, d) VALUES (1, 'textme', 1.3, TRUE), (2, 'yolo', 1.3, FALSE);
483+
```
484+
310485
#### denormalized fields trigger
311486

312487
```sql
@@ -337,6 +512,33 @@ new.f;
337512
END;
338513
```
339514

515+
#### comments
516+
517+
the `smart_comments` helpers is meant for use with [graphile](https://www.graphile.org/postgraphile/), but you can use any comment string
518+
519+
```sql
520+
select deparser.expression(
521+
ast.comment_stmt(
522+
v_objtype := 'OBJECT_TABCONSTRAINT',
523+
v_object := to_jsonb(ARRAY[
524+
ast.string('my_schema'),
525+
ast.string('my_table'),
526+
ast.string('my_constraint')
527+
]),
528+
v_comment := ast_helpers.smart_comments(
529+
tags := '{"type":"object","props":["id","url","title","tags"]}'::jsonb,
530+
description := 'my description'
531+
)
532+
)
533+
);
534+
```
535+
536+
produces
537+
538+
```sql
539+
COMMENT ON CONSTRAINT my_constraint ON my_schema.my_table IS E'@type object\n@props id\n@props url\n@props title\n@props tags\nmy description'
540+
```
541+
340542
## installation
341543

342544
If you know how to use extensions, or perhaps even just grab the sql and run with it, you can use the bundled extension here [packages/ast/sql](packages/ast/sql). If you run it manually, you just need to make sure to install the `uuid-ossp` extension.
@@ -435,10 +637,12 @@ Our latest is built with `13-latest` branch from libpg_query
435637
|--------------------------|-------------|---------------------|---------|
436638
| 13 | 13-latest | Active development | `latest`
437639

438-
## Special Thanks and Resources
640+
## Special Thanks and our Community
439641

440642
* [pgsql-parser](https://github.com/pyramation/pgsql-parser)
441643
* [libpg-query-node](https://github.com/pyramation/libpg-query-node)
442644
* [libpg_query](https://github.com/pganalyze/libpg_query)
443645
* [pg_query](https://github.com/lfittl/pg_query)
444646
* [sqitch](https://sqitch.org/)
647+
* [postgraphile](https://www.graphile.org/postgraphile/)
648+
* [launchql](https://github.com/launchql/launchql)

0 commit comments

Comments
 (0)