Skip to content

Commit

Permalink
Add rule to prevent concurrent index creation inside transactions (#335)
Browse files Browse the repository at this point in the history
Add a rule that warns about creating an index with the `CONCURRENTLY` option inside a transaction, since that's not allowed in Postgres. This will resolve #332
  • Loading branch information
alixlahuec authored Jan 12, 2024
1 parent 7417733 commit 5e0b0a9
Show file tree
Hide file tree
Showing 18 changed files with 299 additions and 4 deletions.
6 changes: 6 additions & 0 deletions CHANGELOG.md
Original file line number Diff line number Diff line change
Expand Up @@ -7,6 +7,12 @@ and this project adheres to [Semantic Versioning](https://semver.org/spec/v2.0.0

## [Unreleased]

## v0.27.0 - 2024-01-11

### Added

- added `ban-concurrent-index-creation-in-transaction` rule. Thanks @alixlahuec! (#335)

## v0.26.0 - 2023-12-12

### Changed
Expand Down
2 changes: 1 addition & 1 deletion Cargo.lock

Some generated files are not rendered by default. Learn more about how customized files appear on GitHub.

2 changes: 1 addition & 1 deletion cli/Cargo.toml
Original file line number Diff line number Diff line change
@@ -1,6 +1,6 @@
[package]
name = "squawk"
version = "0.26.0"
version = "0.27.0"
authors = ["Steve Dignam <[email protected]>"]
edition = "2018"
license = "GPL-3.0"
Expand Down
106 changes: 106 additions & 0 deletions docs/docs/ban-concurrent-index-creation-in-transaction.md
Original file line number Diff line number Diff line change
@@ -0,0 +1,106 @@
---
id: ban-concurrent-index-creation-in-transaction
title: ban-concurrent-index-creation-in-transaction
---

## problem

While regular index creation can happen inside a transaction, this is not allowed when the `CONCURRENTLY` option is used.

https://www.postgresql.org/docs/current/sql-createindex.html#SQL-CREATEINDEX-CONCURRENTLY

## solution

Remove surrounding transaction markers if any, and check that the `CREATE INDEX` command is not implicitly wrapped in a transaction.

Instead of:

```sql
BEGIN;
-- <any other commands being run transactionally>
CREATE INDEX CONCURRENTLY "email_idx" ON "app_user" ("email");
COMMIT;
```

Use:

```sql
BEGIN;
-- <any other commands being run transactionally>
COMMIT;

CREATE INDEX CONCURRENTLY "email_idx" ON "app_user" ("email");
```

If you use a migration tool, it may be configured to automatically wrap commands in transactions; if that's the case, check if it supports running commands in a non-transactional context.
For example, with `alembic`:

```python
# migrations/*.py
from alembic import op

def schema_upgrades():
# <any other commands being run transactionally>

# alembic allows non-transactional operations using autocommit
with op.get_context().autocommit_block():
op.create_index(
"email_idx",
"app_user",
["email"],
schema="app",
unique=False,
postgresql_concurrently=True,
)

# <any other commands being run transactionally>

def schema_downgrades():
# <any other downgrade commands>

op.drop_index(
"email_idx",
schema="app",
)

# <any other downgrade commands>
```

Or alternatively:

```python
# migrations/*.py
from alembic import op

def schema_upgrades():
# <any other commands being run transactionally>

# you can also execute BEGIN/COMMIT to delineate transactions
op.execute("COMMIT;")
op.execute("SET statement_timeout = 0;")
op.create_index(
"email_idx",
"app_user",
["email"],
schema="app",
unique=False,
postgresql_concurrently=True,
)

op.execute("BEGIN;")
# <any other commands being run transactionally>

def schema_downgrades():
# <any other downgrade commands>

op.drop_index(
"email_idx",
schema="app",
)

# <any other downgrade commands>
```

## links

https://www.postgresql.org/docs/current/sql-createindex.html#SQL-CREATEINDEX-CONCURRENTLY
1 change: 1 addition & 0 deletions docs/sidebars.js
Original file line number Diff line number Diff line change
Expand Up @@ -27,6 +27,7 @@ module.exports = {
"require-concurrent-index-creation",
"require-concurrent-index-deletion",
"transaction-nesting",
"ban-concurrent-index-creation-in-transaction",
// generator::new-rule-above
],
},
Expand Down
5 changes: 5 additions & 0 deletions docs/src/pages/index.js
Original file line number Diff line number Diff line change
Expand Up @@ -178,6 +178,11 @@ const rules = [
tags: ["locking"],
description: "Ensure migrations use transactions correctly.",
},
{
name: "ban-concurrent-index-creation-in-transaction",
tags: ["schema"],
description: "Prevent forbidden use of transactions during concurrent index creation.",
},
// generator::new-rule-above
]

Expand Down
2 changes: 1 addition & 1 deletion flake.nix
Original file line number Diff line number Diff line change
Expand Up @@ -18,7 +18,7 @@
{
squawk = final.rustPlatform.buildRustPackage {
pname = "squawk";
version = "0.26.0";
version = "0.27.0";

cargoLock = {
lockFile = ./Cargo.lock;
Expand Down
13 changes: 13 additions & 0 deletions linter/src/lib.rs
Original file line number Diff line number Diff line change
Expand Up @@ -9,6 +9,7 @@ extern crate lazy_static;

use crate::errors::CheckSqlError;
use crate::rules::adding_required_field;
use crate::rules::ban_concurrent_index_creation_in_transaction;
use crate::rules::ban_drop_not_null;
use crate::rules::prefer_big_int;
use crate::rules::prefer_identity;
Expand Down Expand Up @@ -106,6 +107,18 @@ lazy_static! {
),
]
},
SquawkRule {
name: RuleViolationKind::BanConcurrentIndexCreationInTransaction,
func: ban_concurrent_index_creation_in_transaction,
messages: vec![
ViolationMessage::Note(
"Concurrent index creation is not allowed inside a transaction.".into()
),
ViolationMessage::Help(
"Build the index outside any transactions.".into()
),
],
},
SquawkRule {
name: RuleViolationKind::BanDropColumn,
func: ban_drop_column,
Expand Down
102 changes: 102 additions & 0 deletions linter/src/rules/ban_concurrent_index_creation_in_transaction.rs
Original file line number Diff line number Diff line change
@@ -0,0 +1,102 @@
use crate::versions::Version;
use crate::violations::{RuleViolation, RuleViolationKind};

use squawk_parser::ast::{RawStmt, Stmt, TransactionStmtKind};

#[must_use]
pub fn ban_concurrent_index_creation_in_transaction(
tree: &[RawStmt],
_pg_version: Option<Version>,
assume_in_transaction: bool,
) -> Vec<RuleViolation> {
let mut in_transaction = assume_in_transaction;
let mut errs = vec![];
for raw_stmt in tree {
match &raw_stmt.stmt {
Stmt::TransactionStmt(stmt) => {
if stmt.kind == TransactionStmtKind::Begin && !in_transaction {
in_transaction = true;
}
if stmt.kind == TransactionStmtKind::Commit {
in_transaction = false;
}
}
Stmt::IndexStmt(stmt) => {
if stmt.concurrent && in_transaction {
errs.push(RuleViolation::new(
RuleViolationKind::BanConcurrentIndexCreationInTransaction,
raw_stmt.into(),
None,
));
}
}
_ => continue,
}
}
errs
}

#[cfg(test)]
mod test_rules {
use insta::assert_debug_snapshot;

use crate::{
check_sql_with_rule,
violations::{RuleViolation, RuleViolationKind},
};

fn lint_sql(sql: &str) -> Vec<RuleViolation> {
check_sql_with_rule(
sql,
&RuleViolationKind::BanConcurrentIndexCreationInTransaction,
None,
false,
)
.unwrap()
}

fn lint_sql_assuming_in_transaction(sql: &str) -> Vec<RuleViolation> {
check_sql_with_rule(
sql,
&RuleViolationKind::BanConcurrentIndexCreationInTransaction,
None,
true,
)
.unwrap()
}

#[test]
fn test_adding_index_concurrently_in_transaction() {
let bad_sql = r#"
-- instead of
BEGIN;
CREATE INDEX CONCURRENTLY "field_name_idx" ON "table_name" ("field_name");
COMMIT;
"#;

assert_debug_snapshot!(lint_sql(bad_sql));

let ok_sql = r#"
-- run outside a transaction
CREATE INDEX CONCURRENTLY "field_name_idx" ON "table_name" ("field_name");
"#;
assert_debug_snapshot!(lint_sql(ok_sql));
}

#[test]
fn test_adding_index_concurrently_in_transaction_with_assume_in_transaction() {
let bad_sql = r#"
-- instead of
CREATE INDEX CONCURRENTLY "field_name_idx" ON "table_name" ("field_name");
"#;

assert_debug_snapshot!(lint_sql_assuming_in_transaction(bad_sql));

let ok_sql = r#"
-- run outside a transaction
COMMIT;
CREATE INDEX CONCURRENTLY "field_name_idx" ON "table_name" ("field_name");
"#;
assert_debug_snapshot!(lint_sql_assuming_in_transaction(ok_sql));
}
}
2 changes: 2 additions & 0 deletions linter/src/rules/mod.rs
Original file line number Diff line number Diff line change
Expand Up @@ -50,3 +50,5 @@ pub mod transaction_nesting;
pub use transaction_nesting::*;
pub mod adding_required_field;
pub use adding_required_field::*;
pub mod ban_concurrent_index_creation_in_transaction;
pub use ban_concurrent_index_creation_in_transaction::*;
Original file line number Diff line number Diff line change
@@ -0,0 +1,5 @@
---
source: linter/src/rules/ban_concurrent_index_creation_in_transaction.rs
expression: lint_sql(ok_sql)
---
[]
Original file line number Diff line number Diff line change
@@ -0,0 +1,23 @@
---
source: linter/src/rules/ban_concurrent_index_creation_in_transaction.rs
expression: lint_sql(bad_sql)
---
[
RuleViolation {
kind: BanConcurrentIndexCreationInTransaction,
span: Span {
start: 25,
len: Some(
76,
),
},
messages: [
Note(
"Concurrent index creation is not allowed inside a transaction.",
),
Help(
"Build the index outside any transactions.",
),
],
},
]
Original file line number Diff line number Diff line change
@@ -0,0 +1,5 @@
---
source: linter/src/rules/ban_concurrent_index_creation_in_transaction.rs
expression: lint_sql_assuming_in_transaction(ok_sql)
---
[]
Original file line number Diff line number Diff line change
@@ -0,0 +1,23 @@
---
source: linter/src/rules/ban_concurrent_index_creation_in_transaction.rs
expression: lint_sql_assuming_in_transaction(bad_sql)
---
[
RuleViolation {
kind: BanConcurrentIndexCreationInTransaction,
span: Span {
start: 0,
len: Some(
92,
),
},
messages: [
Note(
"Concurrent index creation is not allowed inside a transaction.",
),
Help(
"Build the index outside any transactions.",
),
],
},
]
Original file line number Diff line number Diff line change
Expand Up @@ -9,6 +9,7 @@ expression: rule_names
"adding-required-field",
"adding-serial-primary-key-field",
"ban-char-field",
"ban-concurrent-index-creation-in-transaction",
"ban-drop-column",
"ban-drop-database",
"ban-drop-not-null",
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -8,6 +8,7 @@ adding-not-nullable-field
adding-required-field
adding-serial-primary-key-field
ban-char-field
ban-concurrent-index-creation-in-transaction
ban-drop-column
ban-drop-database
ban-drop-not-null
Expand Down
2 changes: 2 additions & 0 deletions linter/src/violations.rs
Original file line number Diff line number Diff line change
Expand Up @@ -59,6 +59,8 @@ pub enum RuleViolationKind {
TransactionNesting,
#[serde(rename = "adding-required-field")]
AddingRequiredField,
#[serde(rename = "ban-concurrent-index-creation-in-transaction")]
BanConcurrentIndexCreationInTransaction,
// generator::new-rule-above
}

Expand Down
2 changes: 1 addition & 1 deletion package.json
Original file line number Diff line number Diff line change
@@ -1,6 +1,6 @@
{
"name": "squawk-cli",
"version": "0.26.0",
"version": "0.27.0",
"description": "linter for PostgreSQL, focused on migrations",
"repository": "[email protected]:sbdchd/squawk.git",
"author": "Steve Dignam <[email protected]>",
Expand Down

0 comments on commit 5e0b0a9

Please sign in to comment.