-
Notifications
You must be signed in to change notification settings - Fork 40
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
The current README is hard to navigate and discourages adding more examples. Having a documentation website should allow us to provide more detailed docs.
- Loading branch information
Showing
34 changed files
with
11,344 additions
and
1 deletion.
There are no files selected for viewing
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -1,3 +1,4 @@ | ||
# don't ever lint node_modules | ||
node_modules | ||
.eslintrc.js | ||
docs |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
|
@@ -6,3 +6,4 @@ coverage/ | |
.terraform/ | ||
.pytest_cache/ | ||
target/ | ||
docs |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,20 @@ | ||
# Dependencies | ||
/node_modules | ||
|
||
# Production | ||
/build | ||
|
||
# Generated files | ||
.docusaurus | ||
.cache-loader | ||
|
||
# Misc | ||
.DS_Store | ||
.env.local | ||
.env.development.local | ||
.env.test.local | ||
.env.production.local | ||
|
||
npm-debug.log* | ||
yarn-debug.log* | ||
yarn-error.log* |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,33 @@ | ||
# Website | ||
|
||
This website is built using [Docusaurus 2](https://v2.docusaurus.io/), a modern static website generator. | ||
|
||
## Installation | ||
|
||
```console | ||
yarn install | ||
``` | ||
|
||
## Local Development | ||
|
||
```console | ||
yarn start | ||
``` | ||
|
||
This command starts a local development server and open up a browser window. Most changes are reflected live without having to restart the server. | ||
|
||
## Build | ||
|
||
```console | ||
yarn build | ||
``` | ||
|
||
This command generates static content into the `build` directory and can be served using any static contents hosting service. | ||
|
||
## Deployment | ||
|
||
```console | ||
GIT_USER=<Your GitHub username> USE_SSH=true yarn deploy | ||
``` | ||
|
||
If you are using GitHub pages for hosting, this command is a convenient way to build the website and push to the `gh-pages` branch. |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,3 @@ | ||
module.exports = { | ||
presets: [require.resolve('@docusaurus/core/lib/babel/preset')], | ||
}; |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,39 @@ | ||
--- | ||
id: adding-field-with-default | ||
title: adding-field-with-default | ||
--- | ||
|
||
:::note Postgres Version | ||
|
||
This lint only applies to Postgres versions less than 11. | ||
::: | ||
|
||
## problem | ||
|
||
On Postgres versions less than 11, adding a field with a `DEFAULT` requires a | ||
table rewrite with an `ACCESS EXCLUSIVE` lock. | ||
|
||
<https://www.postgresql.org/docs/10/sql-altertable.html#SQL-ALTERTABLE-NOTES> | ||
|
||
An `ACCESS EXCLUSIVE` lock blocks reads / writes while the statement is running. | ||
|
||
## solution | ||
|
||
Add the field as nullable, then set a default, backfill, and remove nullabilty. | ||
|
||
Instead of: | ||
|
||
```sql | ||
ALTER TABLE "core_recipe" ADD COLUMN "foo" integer DEFAULT 10 NOT NULL; | ||
``` | ||
|
||
Use: | ||
|
||
```sql | ||
ALTER TABLE "core_recipe" ADD COLUMN "foo" integer; | ||
ALTER TABLE "core_recipe" ALTER COLUMN "foo" SET DEFAULT 10; | ||
-- backfill column in batches | ||
ALTER TABLE "core_recipe" ALTER COLUMN "foo" SET NOT NULL; | ||
``` | ||
|
||
We add our column as nullable, set a default for new rows, backfill our column (ideally done in batches to limit locking), and finally remove nullability. |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,79 @@ | ||
--- | ||
id: adding-foreign-key-constraint | ||
title: adding-foreign-key-constraint | ||
--- | ||
|
||
A foreign key constraint should be added with `NOT VALID`. | ||
|
||
Adding a foreign key constraint requires a table scan and a `SHARE ROW EXCLUSIVE` lock on both tables, which blocks writes. | ||
|
||
Adding the constraint as `NOT VALID` in one transaction and then using | ||
`VALIDATE` in another transaction will allow writes when adding the | ||
constraint. | ||
|
||
## problem | ||
|
||
Adding a foreign key constraint requires a table scan and a `SHARE ROW EXCLUSIVE` lock on both tables, which blocks writes to each table. | ||
|
||
This means no writes will be allowed to either table while the table you're altering is scanned to validate the constraint. | ||
|
||
## solution | ||
|
||
To prevent blocking writes to tables, add the constraint as `NOT VALID` in one transaction, then `VALIDATE CONSTRAINT` in another. | ||
|
||
While `NOT VALID` prevents row updates while running, it commits instantly if it can get a lock (see ["Safety requirements"](./safe_migrations.md#safety-requirements)). `VALIDATE CONSTRAINT` allows row updates while it scans | ||
the table. | ||
|
||
### adding constraint to existing table | ||
|
||
Instead of: | ||
|
||
```sql | ||
ALTER TABLE "email" ADD CONSTRAINT "fk_user" | ||
FOREIGN KEY ("user_id") REFERENCES "user" ("id"); | ||
``` | ||
|
||
Use: | ||
|
||
```sql | ||
ALTER TABLE "email" ADD CONSTRAINT "fk_user" | ||
FOREIGN KEY ("user_id") REFERENCES "user" ("id") NOT VALID; | ||
ALTER TABLE "email" VALIDATE CONSTRAINT "fk_user"; | ||
``` | ||
|
||
Add the foreign key constraint as `NOT VALID` to prevent locking the `"email"` and `"user"` tables. | ||
|
||
Run `VALIDATE CONSTRAINT` to scan the `"email"` table in the background while reads and writes continue. | ||
|
||
### adding constraint to new table | ||
|
||
Instead of: | ||
|
||
```sql | ||
CREATE TABLE email ( | ||
id BIGINT GENERATED ALWAYS AS IDENTITY, | ||
user_id BIGINT, | ||
email TEXT, | ||
PRIMARY KEY(id), | ||
CONSTRAINT fk_user | ||
FOREIGN KEY ("user_id") | ||
REFERENCES "user" ("id") | ||
); | ||
``` | ||
|
||
Use: | ||
|
||
```sql | ||
CREATE TABLE email ( | ||
id BIGINT GENERATED ALWAYS AS IDENTITY, | ||
user_id BIGINT, | ||
email TEXT, | ||
PRIMARY KEY(id) | ||
); | ||
|
||
ALTER TABLE "email" ADD CONSTRAINT "fk_user" | ||
FOREIGN KEY ("user_id") REFERENCES "user" ("id") NOT VALID; | ||
ALTER TABLE "email" VALIDATE CONSTRAINT "fk_user"; | ||
``` | ||
|
||
Create the table, add the foreign key constraint as `NOT VALID`, then `VALIDATE` the constraint. |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,33 @@ | ||
--- | ||
id: adding-not-nullable-field | ||
title: adding-not-nullable-field | ||
--- | ||
|
||
Use a check constraint instead of setting a column as `NOT NULL`. | ||
|
||
## problem | ||
|
||
Adding a column as `NOT NULL` requires a table scan and the `ALTER TABLE` requires | ||
an `ACCESS EXCLUSIVE` lock. Reads and writes will be disabled while this statement is running. | ||
|
||
## solution | ||
|
||
Add a column as nullable and use a check constraint to verify integrity. The check constraint should be added as `NOT NULL` and then validated. | ||
|
||
Instead of: | ||
|
||
```sql | ||
ALTER TABLE "core_recipe" ADD COLUMN "foo" integer DEFAULT 10 NOT NULL; | ||
``` | ||
|
||
Use: | ||
|
||
```sql | ||
ALTER TABLE "core_recipe" ADD COLUMN "foo" integer DEFAULT 10; | ||
ALTER TABLE "core_recipe" ADD CONSTRAINT foo_not_null | ||
CHECK ("foo" IS NOT NULL) NOT VALID; | ||
-- backfill column so it's not null | ||
ALTER TABLE "core_recipe" VALIDATE CONSTRAINT foo_not_null; | ||
``` | ||
|
||
Add the column as nullable, add a check constraint as `NOT VALID` that verifies the column is not null, backfill the column so it no longer contains null values, validate the constraint to verify existing rows are valid. |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,25 @@ | ||
--- | ||
id: adding-serial-primary-key-field | ||
title: adding-serial-primary-key-field | ||
--- | ||
|
||
Outlined in [Citus' 2018 post on tips for Postgres | ||
locking](https://www.citusdata.com/blog/2018/02/22/seven-tips-for-dealing-with-postgres-locks/) | ||
as well as [the Postgres docs](https://www.postgresql.org/docs/current/sql-altertable.html), adding a primary key constraint is a blocking | ||
operation. | ||
|
||
Instead of creating the constraint directly, consider creating the | ||
`CONSTRAINT` `USING` an index. | ||
|
||
From the Postgres docs: | ||
|
||
> To recreate a primary key constraint, without blocking updates while the | ||
> index is rebuilt: | ||
```sql | ||
CREATE UNIQUE INDEX CONCURRENTLY dist_id_temp_idx ON distributors (dist_id); | ||
ALTER TABLE distributors DROP CONSTRAINT distributors_pkey, | ||
ADD CONSTRAINT distributors_pkey PRIMARY KEY USING INDEX dist_id_temp_idx; | ||
``` | ||
|
||
<https://www.postgresql.org/docs/current/sql-altertable.html> |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,40 @@ | ||
--- | ||
id: ban-char-field | ||
title: ban-char-field | ||
--- | ||
|
||
Using `character` is likely a mistake and should almost always be replaced by `text` or `varchar`. | ||
|
||
From the postgres docs: | ||
|
||
> There is no performance difference among these three types, apart from | ||
> increased storage space when using the blank-padded type, and a few extra CPU | ||
> cycles to check the length when storing into a length-constrained column. | ||
> While character(n) has performance advantages in some other database systems, | ||
> there is no such advantage in PostgreSQL; in fact character(n) is usually the | ||
> slowest of the three because of its additional storage costs. In most | ||
> situations text or character varying should be used instead. | ||
<https://www.postgresql.org/docs/10/datatype-character.html> | ||
|
||
See the [`prefer-text-field`](./prefer-text-field.md) rule for info on the advantages of `text` over `varchar`. | ||
|
||
Instead of: | ||
|
||
```sql | ||
CREATE TABLE "app_user" ( | ||
"id" serial NOT NULL PRIMARY KEY, | ||
"name" char(100) NOT NULL, | ||
"email" character NOT NULL, | ||
); | ||
``` | ||
|
||
Use: | ||
|
||
```sql | ||
CREATE TABLE "app_user" ( | ||
"id" serial NOT NULL PRIMARY KEY, | ||
"name" varchar(100) NOT NULL, | ||
"email" TEXT NOT NULL, | ||
); | ||
``` |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,6 @@ | ||
--- | ||
id: ban-drop-database | ||
title: ban-drop-database | ||
--- | ||
|
||
Dropping a database may break existing clients. |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,11 @@ | ||
--- | ||
id: changing-column-type | ||
title: changing-column-type | ||
--- | ||
|
||
Changing a column type requires an `ACCESS EXCLUSIVE` lock on the table which blocks reads. | ||
|
||
Changing the type of the column may also break other clients reading from the | ||
table. | ||
|
||
<https://www.postgresql.org/docs/current/sql-altertable.html#SQL-ALTERTABLE-NOTES> |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,65 @@ | ||
--- | ||
id: cli | ||
title: CLI | ||
--- | ||
|
||
## Usage | ||
|
||
```bash | ||
# lint a file or multiple | ||
squawk migration_001.sql migration_002.sql migration_003.sql | ||
|
||
# lint from standard in | ||
cat migration.sql | squawk | ||
``` | ||
|
||
### `squawk --help` | ||
|
||
``` | ||
squawk | ||
Find problems in your SQL | ||
USAGE: | ||
squawk [FLAGS] [OPTIONS] [paths]... [SUBCOMMAND] | ||
FLAGS: | ||
-h, --help | ||
Prints help information | ||
--list-rules | ||
List all available rules | ||
-V, --version | ||
Prints version information | ||
--verbose | ||
Enable debug logging output | ||
OPTIONS: | ||
--dump-ast <dump-ast> | ||
Output AST in JSON [possible values: Raw, Parsed, Debug] | ||
-e, --exclude <exclude>... | ||
Exclude specific warnings | ||
For example: --exclude=require-concurrent-index-creation,ban-drop-database | ||
--explain <explain> | ||
Provide documentation on the given rule | ||
--reporter <reporter> | ||
Style of error reporting [possible values: Tty, Gcc, Json] | ||
--stdin-filepath <stdin-filepath> | ||
Path to use in reporting for stdin | ||
ARGS: | ||
<paths>... | ||
Paths to search | ||
SUBCOMMANDS: | ||
help Prints this message or the help of the given subcommand(s) | ||
upload-to-github Comment on a PR with Squawk's results | ||
``` |
Oops, something went wrong.