forked from repo-mirrors/sqlfluff
365 lines
8.8 KiB
YAML
365 lines
8.8 KiB
YAML
rule: AL05
|
|
|
|
test_fail_table_alias_not_referenced_1:
|
|
# Aliases not referenced.
|
|
fail_str: SELECT * FROM my_tbl AS foo
|
|
fix_str: SELECT * FROM my_tbl
|
|
|
|
test_fail_table_alias_not_referenced_1_subquery:
|
|
# Aliases not referenced.
|
|
fail_str: SELECT * FROM (SELECT * FROM my_tbl AS foo)
|
|
fix_str: SELECT * FROM (SELECT * FROM my_tbl)
|
|
|
|
test_pass_table_alias_referenced_subquery:
|
|
pass_str: SELECT * FROM (SELECT foo.bar FROM my_tbl AS foo)
|
|
|
|
test_pass_table_alias_referenced:
|
|
pass_str: SELECT * FROM my_tbl AS foo JOIN other_tbl on other_tbl.x = foo.x
|
|
|
|
test_pass_unaliased_table_referenced:
|
|
# AL05 fix with https://github.com/sqlfluff/sqlfluff/issues/449
|
|
pass_str: select ps.*, pandgs.blah from ps join pandgs using(moo)
|
|
|
|
test_ignore_bigquery_value_table_functions:
|
|
# AL05 fix with https://github.com/sqlfluff/sqlfluff/issues/356
|
|
pass_str: |
|
|
select *
|
|
from unnest(generate_timestamp_array(
|
|
'2020-01-01', '2020-01-30', interval 1 day)) as ts
|
|
configs:
|
|
core:
|
|
dialect: bigquery
|
|
|
|
test_ignore_postgres_value_table_functions:
|
|
# AL05 fix with https://github.com/sqlfluff/sqlfluff/issues/3051
|
|
pass_str: |
|
|
SELECT json_build_object(
|
|
'name', 'ticket_status',
|
|
'type', 'enum',
|
|
'values', json_agg(status_name)
|
|
)
|
|
FROM unnest(enum_range(NULL::my_enum)) AS status_name;
|
|
configs:
|
|
core:
|
|
dialect: postgres
|
|
|
|
test_ignore_postgres_value_table_functions_generate_series:
|
|
# AL05 fix with https://github.com/sqlfluff/sqlfluff/issues/3462
|
|
pass_str: |
|
|
SELECT
|
|
date_trunc('day', dd):: timestamp with time zone
|
|
FROM generate_series (
|
|
'2022-02-01'::timestamp , NOW()::timestamp , '1 day'::interval
|
|
) dd ;
|
|
configs:
|
|
core:
|
|
dialect: postgres
|
|
|
|
test_fail_table_alias_not_referenced_2:
|
|
# Similar to test_1, but with implicit alias.
|
|
fail_str: SELECT * FROM my_tbl foo
|
|
fix_str: SELECT * FROM my_tbl
|
|
|
|
test_fail_table_alias_not_referenced_2_subquery:
|
|
# Aliases not referenced.
|
|
fail_str: SELECT * FROM (SELECT * FROM my_tbl foo)
|
|
fix_str: SELECT * FROM (SELECT * FROM my_tbl)
|
|
|
|
test_pass_subquery_alias_not_referenced:
|
|
pass_str: select * from (select 1 as a) subquery
|
|
|
|
test_pass_bigquery_unaliased_table_with_hyphens:
|
|
# Test non-quoted table name containing hyphens: https://github.com/sqlfluff/sqlfluff/issues/895
|
|
# This is more of a smoke test to exercise the
|
|
# ObjectReferenceSegment.extract_reference() function, which is used by AL05
|
|
# and in turn calls HyphenatedObjectReferenceSegment.iter_raw_references().
|
|
pass_str: |
|
|
select *
|
|
from project-a.dataset-b.table-c
|
|
configs:
|
|
core:
|
|
dialect: bigquery
|
|
|
|
test_pass_bigquery_aliased_table_with_ticks_referenced:
|
|
# Test ambiguous column reference caused by use of BigQuery structure fields.
|
|
# Here, 'et2' could either be a schema name or a table name.
|
|
# https://github.com/sqlfluff/sqlfluff/issues/1079
|
|
pass_str: |
|
|
SELECT et2.txn.amount
|
|
FROM `example_dataset2.example_table2` AS et2
|
|
configs:
|
|
core:
|
|
dialect: bigquery
|
|
|
|
test_pass_tsql_object_reference_override:
|
|
# T-SQL Overrides the ObjectReferenceSegment so needs to have the _level_to_int
|
|
# static method set (as a static method!) or rule AL05 fails.
|
|
# https://github.com/sqlfluff/sqlfluff/issues/1669
|
|
pass_str: SELECT a FROM b
|
|
configs:
|
|
core:
|
|
dialect: tsql
|
|
|
|
test_pass_subselect_uses_alias_1:
|
|
pass_str: |
|
|
SELECT
|
|
col1,
|
|
(
|
|
SELECT count(*)
|
|
FROM base
|
|
WHERE a.col2 = base.col2
|
|
)
|
|
FROM
|
|
without_dup AS a
|
|
|
|
test_pass_subselect_uses_alias_2:
|
|
pass_str: |
|
|
select
|
|
COL_A
|
|
, COL_B
|
|
from INSERTS INS
|
|
where COL_B != (select max(COL_B) from INSERTS X where INS.COL_A = X.COL_A)
|
|
|
|
test_pass_subselect_uses_alias_3:
|
|
pass_str: |
|
|
SELECT col_1
|
|
FROM table_a AS a
|
|
WHERE NOT EXISTS (SELECT TRUE FROM table_b AS b WHERE a.col_4 = b.col_1)
|
|
|
|
test_ansi_function_not_table_parameter:
|
|
fail_str: |
|
|
SELECT TO_JSON_STRING(t)
|
|
FROM my_table AS t
|
|
fix_str: |
|
|
SELECT TO_JSON_STRING(t)
|
|
FROM my_table
|
|
|
|
test_bigquery_function_takes_tablealias_parameter:
|
|
pass_str: |
|
|
SELECT TO_JSON_STRING(t)
|
|
FROM my_table AS t
|
|
configs:
|
|
core:
|
|
dialect: bigquery
|
|
|
|
test_bigquery_function_takes_tablealias_column_parameter:
|
|
pass_str: |
|
|
SELECT TO_JSON_STRING(t.c)
|
|
FROM my_table AS t
|
|
configs:
|
|
core:
|
|
dialect: bigquery
|
|
|
|
test_bigquery_function_takes_tablealias_column_struct_parameter:
|
|
pass_str: |
|
|
SELECT TO_JSON_STRING(t.c.structure)
|
|
FROM my_table AS t
|
|
configs:
|
|
core:
|
|
dialect: bigquery
|
|
|
|
test_snowflake_delete_cte:
|
|
fail_str: |
|
|
DELETE FROM MYTABLE1
|
|
USING (
|
|
WITH MYCTE AS (SELECT COLUMN2 FROM MYTABLE3 AS MT3)
|
|
SELECT COLUMN3 FROM MYTABLE3
|
|
) X
|
|
WHERE COLUMN1 = X.COLUMN3
|
|
fix_str: |
|
|
DELETE FROM MYTABLE1
|
|
USING (
|
|
WITH MYCTE AS (SELECT COLUMN2 FROM MYTABLE3)
|
|
SELECT COLUMN3 FROM MYTABLE3
|
|
) X
|
|
WHERE COLUMN1 = X.COLUMN3
|
|
configs:
|
|
core:
|
|
dialect: snowflake
|
|
|
|
test_pass_exasol_values_clause:
|
|
pass_str: |
|
|
SELECT *
|
|
FROM (
|
|
VALUES (1, 2), (3, 4)
|
|
)
|
|
configs:
|
|
core:
|
|
dialect: exasol
|
|
|
|
test_fail_exasol_values_clause:
|
|
fail_str: |
|
|
SELECT *
|
|
FROM (
|
|
VALUES (1, 2), (3, 4)
|
|
) AS t(c1, c2)
|
|
fix_str: |
|
|
SELECT *
|
|
FROM (
|
|
VALUES (1, 2), (3, 4)
|
|
)
|
|
configs:
|
|
core:
|
|
dialect: exasol
|
|
|
|
test_pass_sparksql_values_clause:
|
|
pass_str: |
|
|
SELECT *
|
|
FROM (
|
|
VALUES (1, 2), (3, 4)
|
|
)
|
|
configs:
|
|
core:
|
|
dialect: sparksql
|
|
|
|
test_fail_sparksql_values_clause:
|
|
fail_str: |
|
|
SELECT *
|
|
FROM (
|
|
VALUES (1, 2), (3, 4)
|
|
) AS t(c1, c2)
|
|
fix_str: |
|
|
SELECT *
|
|
FROM (
|
|
VALUES (1, 2), (3, 4)
|
|
)
|
|
configs:
|
|
core:
|
|
dialect: sparksql
|
|
|
|
test_pass_snowflake_values:
|
|
# Tests a fix for issue 3301.
|
|
pass_str: |
|
|
SELECT
|
|
thing_1
|
|
, thing_2
|
|
FROM VALUES
|
|
( 'foo', 'bar')
|
|
, ( 'foo', 'bar')
|
|
my_table_alias(thing_1, thing_2)
|
|
configs:
|
|
core:
|
|
dialect: snowflake
|
|
|
|
test_pass_tsql_values_clause_in_parentheses:
|
|
# Tests a fix for issue 3522. In tsql, the parentheses surrounding "values" are
|
|
# required (otherwise syntax error). SQLFluff was incorrectly complaining that
|
|
# the alias 't' was unused.
|
|
pass_str: |
|
|
SELECT *
|
|
FROM (VALUES
|
|
('a1', 'b1'),
|
|
('a2', 'b2'),
|
|
('a3', 'b3')) t(a,b)
|
|
configs:
|
|
core:
|
|
dialect: tsql
|
|
|
|
test_pass_join_on_expression_in_parentheses:
|
|
pass_str: |
|
|
SELECT table1.c1
|
|
FROM
|
|
table1 AS tbl1
|
|
INNER JOIN table2 AS tbl2 ON (tbl2.col2 = tbl1.col2)
|
|
INNER JOIN table3 AS tbl3 ON (tbl3.col3 = tbl2.col3)
|
|
|
|
test_pass_bigquery_qualify_clause:
|
|
pass_str: |
|
|
SELECT *
|
|
FROM
|
|
table1 AS tbl1
|
|
INNER JOIN tbl2 AS tbl2
|
|
WHERE TRUE
|
|
QUALIFY ROW_NUMBER() OVER (
|
|
PARTITION BY tbl1.col1
|
|
ORDER BY tbl2.col3
|
|
) = 1
|
|
configs:
|
|
core:
|
|
dialect: bigquery
|
|
|
|
test_pass_bigquery_nested_inner_join:
|
|
pass_str: |
|
|
with abh as (
|
|
select
|
|
ceb.emailaddresskey,
|
|
dac.accountkey
|
|
from table2 as dac
|
|
inner join table3 as ceb
|
|
on ceb.col2 = dac.col2
|
|
)
|
|
select col1
|
|
from table1 as abg
|
|
inner join abh
|
|
on abg.col1 = abh.col1
|
|
configs:
|
|
core:
|
|
dialect: bigquery
|
|
|
|
test_fail_snowflake_flatten_function:
|
|
# Tests a fix for issue 3178.
|
|
fail_str: |
|
|
SELECT
|
|
r.rec:foo::string,
|
|
value:bar::string
|
|
FROM foo.bar AS r, LATERAL FLATTEN(input => rec:result) AS x
|
|
fix_str: |
|
|
SELECT
|
|
r.rec:foo::string,
|
|
value:bar::string
|
|
FROM foo.bar AS r, LATERAL FLATTEN(input => rec:result)
|
|
configs:
|
|
core:
|
|
dialect: snowflake
|
|
|
|
test_pass_derived_query_requires_alias_1:
|
|
# Case 1: Simple derived query
|
|
pass_str: |
|
|
SELECT * FROM (
|
|
SELECT 1
|
|
) as a
|
|
|
|
test_pass_derived_query_requires_alias_2:
|
|
# Case 2: Derived query uses set operation (UNION)
|
|
pass_str: |
|
|
SELECT * FROM (
|
|
SELECT col FROM dbo.tab
|
|
UNION
|
|
SELECT -1 AS col
|
|
) AS a
|
|
|
|
test_pass_derived_query_requires_alias_3:
|
|
# Case 3: Derived query includes a WITH statement
|
|
pass_str: |
|
|
SELECT * FROM (
|
|
WITH foo AS (
|
|
SELECT col FROM dbo.tab
|
|
)
|
|
SELECT * FROM foo
|
|
) AS a
|
|
|
|
test_pass_redshift_semi_structured_op:
|
|
# Redshift _requires_ aliasing when doing semi-structured operations.
|
|
# https://docs.aws.amazon.com/redshift/latest/dg/query-super.html#unnest
|
|
# The logic here should be that if references _overlap_ (i.e. some
|
|
# aliases refer to other tables in the same FROM clause).
|
|
pass_str: |
|
|
SELECT tt.resource_id
|
|
FROM top_table AS tt
|
|
, tt.nested_column AS co
|
|
configs:
|
|
core:
|
|
dialect: redshift
|
|
|
|
test_pass_postgres_values_clause:
|
|
pass_str: |
|
|
SELECT *
|
|
FROM (
|
|
VALUES
|
|
(1, 2),
|
|
(3, 4)
|
|
) AS t (x, y)
|
|
configs:
|
|
core:
|
|
dialect: postgres
|