|
1 |
| -# LaunchQL |
| 1 | +# PostgreSQL ASTs in PostgreSQL |
2 | 2 |
|
3 |
| -## API info |
| 3 | +This project is the plpgsql companion to https://github.com/pyramation/pgsql-parser. A PostgreSQL AST toolkit and deparser, written in pure plpgsql. |
4 | 4 |
|
5 |
| -If you're on the mobile dev team, this is probably useful! |
| 5 | +## Why? |
6 | 6 |
|
7 |
| -* [API info](docs/readme.md) |
| 7 | +Because string concatenation is bad, and ASTs are the DNA of software itself. |
8 | 8 |
|
9 |
| -## Cloud Functions |
| 9 | +### a note on compatibility |
10 | 10 |
|
11 |
| -* [Cloud Functions](docs/cloud-fns.md) |
| 11 | +Written in pure plpgsql so that it can be installed anywhere, including managed RDBMS environments that don't support untrusted extensions. |
| 12 | +## Usage |
12 | 13 |
|
13 |
| -* [Cloud Functions Quickstart](docs/cloud-functions-quickstart.md) |
| 14 | +Use the `deparser.deparse()` function to deparse Postgres ASTs, in SQL: |
14 | 15 |
|
15 |
| -## postgres |
| 16 | +```sql |
| 17 | +select deparser.deparse( $1::jsonb ); |
| 18 | +``` |
16 | 19 |
|
17 |
| -* [Policy Templates](docs/rls/templates.md) |
18 |
| -* [Postgres Testing](docs/postgres.md) |
| 20 | +## Examples |
19 | 21 |
|
20 |
| -# Development |
| 22 | +#### alter table add column |
21 | 23 |
|
22 |
| -## start the postgres db process |
| 24 | +```sql |
| 25 | +select |
| 26 | + deparser.expression( |
| 27 | + ast_helpers.alter_table_add_column( |
| 28 | + v_schema_name := 'myschema', |
| 29 | + v_table_name := 'mytable', |
| 30 | + v_column_name := 'mycolumn', |
| 31 | + v_column_type := 'Geometry(Polygon, 4326)' :: text |
| 32 | + ) |
| 33 | + ); |
| 34 | +``` |
23 | 35 |
|
24 |
| -First you'll want to start the postgres docker (you can also just use `docker-compose up -d`): |
| 36 | +produces |
25 | 37 |
|
26 |
| -```sh |
27 |
| -make up |
| 38 | +```sql |
| 39 | +ALTER TABLE |
| 40 | + myschema.mytable |
| 41 | +ADD |
| 42 | + COLUMN mycolumn pg_catalog.Geometry(Polygon, 4326); |
28 | 43 | ```
|
29 | 44 |
|
30 |
| -## install modules |
| 45 | +#### drop function |
31 | 46 |
|
32 |
| -Install modules |
| 47 | +```sql |
| 48 | +SELECT deparser.deparse(ast_helpers.drop_function( |
| 49 | + v_schema_name := 'schema', |
| 50 | + v_function_name := 'name' |
| 51 | +)); |
| 52 | +``` |
| 53 | +produces |
33 | 54 |
|
34 |
| -```sh |
35 |
| -yarn install |
| 55 | +```sql |
| 56 | +DROP FUNCTION schema.name; |
36 | 57 | ```
|
37 | 58 |
|
38 |
| -## install the Postgres extensions |
| 59 | +#### create function |
| 60 | + |
| 61 | +Here is an example that uses `create_function`: |
| 62 | + |
| 63 | +```sql |
| 64 | +SELECT deparser.deparse(ast_helpers.create_function( |
| 65 | + v_schema_name := 'schema', |
| 66 | + v_function_name := 'name', |
| 67 | + v_type := 'TRIGGER', |
| 68 | + v_parameters := to_jsonb(ARRAY[ |
| 69 | + ast_helpers.simple_param( |
| 70 | + 'param1', |
| 71 | + 'text' |
| 72 | + ), |
| 73 | + ast_helpers.simple_param( |
| 74 | + 'active', |
| 75 | + 'bool' |
| 76 | + ), |
| 77 | + ast_helpers.simple_param( |
| 78 | + 'sid', |
| 79 | + 'uuid', |
| 80 | + 'uuid_generate_v4()' |
| 81 | + ), |
| 82 | + ast_helpers.simple_param( |
| 83 | + 'description', |
| 84 | + 'text', |
| 85 | + 'NULL' |
| 86 | + ), |
| 87 | + ast_helpers.simple_param( |
| 88 | + 'tags', |
| 89 | + 'text[]', |
| 90 | + ast.a_const(ast.null()) |
| 91 | + ) |
| 92 | + ]::jsonb[]), |
| 93 | + v_body := 'code here', |
| 94 | + v_volatility := 'volatile', |
| 95 | + v_language := 'plpgsql', |
| 96 | + v_security := 0 |
| 97 | +)); |
| 98 | +``` |
39 | 99 |
|
40 |
| -Now that the postgres process is running, install the extensions: |
| 100 | +produces |
| 101 | + |
| 102 | +```sql |
| 103 | +CREATE FUNCTION schema.name ( |
| 104 | + param1 text, |
| 105 | + active bool, |
| 106 | + sid uuid DEFAULT uuid_generate_v4(), |
| 107 | + description text DEFAULT NULL, |
| 108 | + tags text[] DEFAULT NULL |
| 109 | +) RETURNS TRIGGER AS $LQLCODEZ$ |
| 110 | + code here |
| 111 | +$LQLCODEZ$ LANGUAGE plpgsql VOLATILE; |
| 112 | + ``` |
| 113 | + |
| 114 | +#### alter policy |
| 115 | + |
| 116 | +```sql |
| 117 | +SELECT deparser.deparse(ast_helpers.alter_policy( |
| 118 | + v_policy_name := 'mypolicy', |
| 119 | + v_schema_name := 'schemanamed', |
| 120 | + v_table_name := 'mytable', |
| 121 | + v_roles := '{authenticated}'::text[], |
| 122 | + v_qual := ast.bool_expr('OR_EXPR', to_jsonb(ARRAY[ |
| 123 | + ast.a_expr(v_kind := 'AEXPR_OP', |
| 124 | + v_lexpr := ast.column_ref( |
| 125 | + v_fields := to_jsonb(ARRAY[ ast.string('responder_id') ]) |
| 126 | + ), |
| 127 | + v_name := to_jsonb(ARRAY[ast.string('=')]), |
| 128 | + v_rexpr := ast.func_call( |
| 129 | + v_funcname := to_jsonb(ARRAY[ ast.string('dbe'), ast.string('get_uid') ]), |
| 130 | + v_args := to_jsonb(ARRAY[ ast.string('c'), ast.string('b') ]) |
| 131 | + ) |
| 132 | + ), |
| 133 | + ast.a_expr(v_kind := 'AEXPR_OP', |
| 134 | + v_lexpr := ast.column_ref( |
| 135 | + v_fields := to_jsonb(ARRAY[ ast.string('requester_id') ]) |
| 136 | + ), |
| 137 | + v_name := to_jsonb(ARRAY[ast.string('=')]), |
| 138 | + v_rexpr := ast.func_call( |
| 139 | + v_funcname := to_jsonb(ARRAY[ ast.string('dbe'), ast.string('get_other_uid') ]), |
| 140 | + v_args := to_jsonb(ARRAY[ ast.string('c'), ast.string('b') ]) |
| 141 | + ) |
| 142 | + ) |
| 143 | + ])), |
| 144 | + v_with_check := NULL |
| 145 | +)); |
| 146 | +``` |
| 147 | + |
| 148 | +produces |
| 149 | + |
| 150 | +```sql |
| 151 | +ALTER POLICY mypolicy |
| 152 | + ON schemanamed.mytable TO authenticated USING ( |
| 153 | + responder_id = dbe.get_uid(c, b) |
| 154 | + OR requester_id = dbe.get_other_uid(c, b) |
| 155 | +); |
| 156 | +``` |
| 157 | +## installation |
| 158 | + |
| 159 | +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. |
| 160 | + |
| 161 | +To do an automated recursive deploy that automatically installs deps, you can use `sqitch` and `launchql`. |
| 162 | +### Recursive Deploy |
| 163 | + |
| 164 | +If you already have `lql` and `sqitch`, simply run this |
41 | 165 |
|
42 | 166 | ```sh
|
43 |
| -make install |
| 167 | +createdb launchql |
| 168 | +lql deploy --recursive --database launchql --yes --project ast |
44 | 169 | ```
|
45 | 170 |
|
46 |
| -This basically `ssh`s into the postgres instance with the `packages/` folder mounted as a volume, and installs the bundled sql code as pgxn extensions. |
| 171 | +If you don't have them installed, continue below. |
| 172 | +## developing |
| 173 | +#### Install `psql` |
| 174 | + |
| 175 | +Install `psql` without actually running the database. On mac you can use |
| 176 | + |
| 177 | +`brew install libpq` |
| 178 | + |
| 179 | +Or you can install the full-blown postgres locally, but it is recommended that you shut the service down. You'll be using `psql` to connect to the postgres that runs inside of a docker container. |
47 | 180 |
|
| 181 | +#### Install `sqitch` |
| 182 | + |
| 183 | +https://sqitch.org/ |
| 184 | + |
| 185 | +mac users can use brew |
| 186 | + |
| 187 | +``` |
| 188 | +brew install sqitch --with-postgres-support --without-postgresql |
| 189 | +``` |
| 190 | + |
| 191 | +or for brew sqitch docs: https://github.com/sqitchers/homebrew-sqitch |
| 192 | + |
| 193 | +#### Install `launchql` |
| 194 | + |
| 195 | +You'll want to install [launchql](https://github.com/launchql/launchql) to run `lql` commands |
| 196 | + |
| 197 | +```sh |
| 198 | +npm install -g @launchql/cli |
| 199 | +``` |
48 | 200 | ## testing
|
| 201 | +### start the postgres db process |
49 | 202 |
|
50 |
| -Testing will load all your latest sql changes and create fresh, populated databases for each sqitch module in `packages/`. |
| 203 | +Start the postgres docker |
51 | 204 |
|
52 | 205 | ```sh
|
53 |
| -yarn test:watch |
| 206 | +docker-compose up -d |
54 | 207 | ```
|
55 | 208 |
|
56 |
| -## building new modules |
| 209 | +### install modules |
57 | 210 |
|
58 |
| -Create a new folder in `packages/` |
| 211 | +This command leverages npm to pull some SQL dependencies. |
59 | 212 |
|
60 | 213 | ```sh
|
61 |
| -lql init |
| 214 | +yarn install |
62 | 215 | ```
|
63 | 216 |
|
64 |
| -Then, run a generator: |
| 217 | +### install testing roles |
65 | 218 |
|
66 | 219 | ```sh
|
67 |
| -lql generate |
| 220 | +psql < ./bootstrap-roles.sql |
| 221 | +psql < ./bootstrap-test-roles.sql |
68 | 222 | ```
|
| 223 | +### install the Postgres extensions |
69 | 224 |
|
70 |
| -You can also add arguments if you already know what you want to do: |
| 225 | +Now install the extensions: |
71 | 226 |
|
72 | 227 | ```sh
|
73 |
| -lql generate schema --schema myschema |
74 |
| -lql generate table --schema myschema --table mytable |
| 228 | +make install |
75 | 229 | ```
|
76 | 230 |
|
77 |
| -## deploy code as extensions |
| 231 | +This basically `ssh`s into the postgres instance with the `packages/` folder mounted as a volume, and installs the bundled sql code as pgxn extensions. |
78 | 232 |
|
79 |
| -`cd` into `packages/<module>`, and run `lql package`. This will make an sql file in `packages/<module>/sql/` used for `CREATE EXTENSION` calls to install your sqitch module as an extension. |
| 233 | +### testing |
80 | 234 |
|
81 |
| -## recursive deploy |
| 235 | +Testing will load all your latest sql changes and create fresh, populated databases for each sqitch module in `packages/`. |
82 | 236 |
|
83 |
| -You can also deploy all modules utilizing versioning as sqtich modules. Remove `--createdb` if you already created your db: |
| 237 | +For example |
84 | 238 |
|
85 | 239 | ```sh
|
86 |
| -lql deploy awesome-db --yes --recursive --createdb |
| 240 | +cd ./packages/ast |
| 241 | +yarn test:watch |
87 | 242 | ```
|
0 commit comments