Skip to content

Commit

Permalink
New Rule L056: 'SP_' prefix should not be used for user-defined store…
Browse files Browse the repository at this point in the history
…d procedures (#1930)

* New Rule L056: 'SP_' prefix should not be used for user-defined stored procedures in T-SQL.

* Add extra test cases for bracketed/quoted stored procedure names

* Fix unescaped underscores in L056 docstring

* raw docstrings to satisfy flake8 + sphinx

* Remove unnecessary lists

* Use description param of LintResult to avoid escape backslash in docstring from showing during linting

* Black reformat

Co-authored-by: Barry Pollard <barry@tunetheweb.com>
  • Loading branch information
jpy-git and tunetheweb committed Nov 19, 2021
1 parent e508d77 commit d3c40ff
Show file tree
Hide file tree
Showing 2 changed files with 170 additions and 0 deletions.
78 changes: 78 additions & 0 deletions src/sqlfluff/rules/L056.py
@@ -0,0 +1,78 @@
"""Implementation of Rule L056."""
from typing import Optional

from sqlfluff.core.rules.base import BaseRule, LintResult, RuleContext


class Rule_L056(BaseRule):
r"""'SP\_' prefix should not be used for user-defined stored procedures in T-SQL.
| **Anti-pattern**
| The 'SP\_' prefix is used to identify system procedures and
| can adversely affect performance of the user-defined stored procedure.
| It can also break system procedures if there is a naming conflict.
.. code-block:: sql
:force:
CREATE PROCEDURE dbo.sp_pull_data
AS
SELECT
ID,
DataDate,
CaseOutput
FROM table1
| **Best practice**
| Use a different name for the stored procedure.
.. code-block:: sql
:force:
CREATE PROCEDURE dbo.pull_data
AS
SELECT
ID,
DataDate,
CaseOutput
FROM table1
-- Alternatively prefix with 'USP_' to
-- indicate a user-defined stored procedure.
CREATE PROCEDURE dbo.usp_pull_data
AS
SELECT
ID,
DataDate,
CaseOutput
FROM table1
"""

def _eval(self, context: RuleContext) -> Optional[LintResult]:
r"""'SP\_' prefix should not be used for user-defined stored procedures."""
# Rule only applies to T-SQL syntax.
if context.dialect.name != "tsql":
return None

# We are only interested in CREATE PROCEDURE statements.
if context.segment.type != "create_procedure_statement":
return None

# Find the object reference for the stored procedure.
object_reference_segment = next(
(s for s in context.segment.segments if s.type == "object_reference")
)

# We only want to check the stored procedure name.
procedure_segment = object_reference_segment.segments[-1]

# If stored procedure name starts with 'SP\_' then raise lint error.
if procedure_segment.raw_upper.lstrip('["').startswith("SP_"):
"s".lstrip
return LintResult(
procedure_segment,
description="'SP_' prefix should not be used for user-defined stored procedures.",
)

return None
92 changes: 92 additions & 0 deletions test/fixtures/rules/std_rule_cases/L056.yml
@@ -0,0 +1,92 @@
rule: L056

test_fail_sp_prefix_1:
fail_str: |
CREATE PROCEDURE dbo.sp_pull_data
AS
SELECT
ID,
DataDate,
CaseOutput
FROM table1
configs:
core:
dialect: tsql

test_fail_sp_prefix_2:
fail_str: |
CREATE PROCEDURE dbo.[sp_pull_data]
AS
SELECT
ID,
DataDate,
CaseOutput
FROM table1
configs:
core:
dialect: tsql

test_fail_sp_prefix_3:
fail_str: |
CREATE PROCEDURE dbo."sp_pull_data"
AS
SELECT
ID,
DataDate,
CaseOutput
FROM table1
configs:
core:
dialect: tsql

test_pass_non_sp_prefix_1:
pass_str: |
CREATE PROCEDURE dbo.pull_data
AS
SELECT
ID,
DataDate,
CaseOutput
FROM table1
configs:
core:
dialect: tsql

test_pass_non_sp_prefix_2:
pass_str: |
CREATE PROCEDURE dbo.usp_pull_data
AS
SELECT
ID,
DataDate,
CaseOutput
FROM table1
configs:
core:
dialect: tsql

test_pass_non_sp_prefix_3:
pass_str: |
CREATE PROCEDURE dbo.[usp_pull_data]
AS
SELECT
ID,
DataDate,
CaseOutput
FROM table1
configs:
core:
dialect: tsql

test_pass_non_sp_prefix_4:
pass_str: |
CREATE PROCEDURE dbo."usp_pull_data"
AS
SELECT
ID,
DataDate,
CaseOutput
FROM table1
configs:
core:
dialect: tsql

0 comments on commit d3c40ff

Please sign in to comment.