Commit e529cd4f authored by Robert Haas's avatar Robert Haas

Suggest to the user the column they may have meant to reference.

Error messages informing the user that no such column exists can
sometimes provoke a perplexed response.  This often happens due to
a subtle typo in the column name or, perhaps less likely, in the
alias name.  To speed discovery of what the real issue is in such
cases, we'll now search the range table for approximate matches.
If there are one or two such matches that are good enough to think
that they might be what the user intended to type, and better than
all other approximate matches, we'll issue a hint suggesting that
the user might have intended to reference those columns.

Peter Geoghegan and Robert Haas
parent bbfd7eda
...@@ -556,7 +556,8 @@ transformColumnRef(ParseState *pstate, ColumnRef *cref) ...@@ -556,7 +556,8 @@ transformColumnRef(ParseState *pstate, ColumnRef *cref)
colname = strVal(field2); colname = strVal(field2);
/* Try to identify as a column of the RTE */ /* Try to identify as a column of the RTE */
node = scanRTEForColumn(pstate, rte, colname, cref->location); node = scanRTEForColumn(pstate, rte, colname, cref->location,
0, NULL);
if (node == NULL) if (node == NULL)
{ {
/* Try it as a function call on the whole row */ /* Try it as a function call on the whole row */
...@@ -601,7 +602,8 @@ transformColumnRef(ParseState *pstate, ColumnRef *cref) ...@@ -601,7 +602,8 @@ transformColumnRef(ParseState *pstate, ColumnRef *cref)
colname = strVal(field3); colname = strVal(field3);
/* Try to identify as a column of the RTE */ /* Try to identify as a column of the RTE */
node = scanRTEForColumn(pstate, rte, colname, cref->location); node = scanRTEForColumn(pstate, rte, colname, cref->location,
0, NULL);
if (node == NULL) if (node == NULL)
{ {
/* Try it as a function call on the whole row */ /* Try it as a function call on the whole row */
...@@ -659,7 +661,8 @@ transformColumnRef(ParseState *pstate, ColumnRef *cref) ...@@ -659,7 +661,8 @@ transformColumnRef(ParseState *pstate, ColumnRef *cref)
colname = strVal(field4); colname = strVal(field4);
/* Try to identify as a column of the RTE */ /* Try to identify as a column of the RTE */
node = scanRTEForColumn(pstate, rte, colname, cref->location); node = scanRTEForColumn(pstate, rte, colname, cref->location,
0, NULL);
if (node == NULL) if (node == NULL)
{ {
/* Try it as a function call on the whole row */ /* Try it as a function call on the whole row */
......
...@@ -1779,7 +1779,7 @@ ParseComplexProjection(ParseState *pstate, char *funcname, Node *first_arg, ...@@ -1779,7 +1779,7 @@ ParseComplexProjection(ParseState *pstate, char *funcname, Node *first_arg,
((Var *) first_arg)->varno, ((Var *) first_arg)->varno,
((Var *) first_arg)->varlevelsup); ((Var *) first_arg)->varlevelsup);
/* Return a Var if funcname matches a column, else NULL */ /* Return a Var if funcname matches a column, else NULL */
return scanRTEForColumn(pstate, rte, funcname, location); return scanRTEForColumn(pstate, rte, funcname, location, 0, NULL);
} }
/* /*
......
This diff is collapsed.
...@@ -95,6 +95,15 @@ varstr_levenshtein(const char *source, int slen, const char *target, int tlen, ...@@ -95,6 +95,15 @@ varstr_levenshtein(const char *source, int slen, const char *target, int tlen,
#define STOP_COLUMN m #define STOP_COLUMN m
#endif #endif
/*
* A common use for Levenshtein distance is to match attributes when building
* diagnostic, user-visible messages. Restrict the size of
* MAX_LEVENSHTEIN_STRLEN at compile time so that this is guaranteed to
* work.
*/
StaticAssertStmt(NAMEDATALEN <= MAX_LEVENSHTEIN_STRLEN,
"Levenshtein hinting mechanism restricts NAMEDATALEN");
m = pg_mbstrlen_with_len(source, slen); m = pg_mbstrlen_with_len(source, slen);
n = pg_mbstrlen_with_len(target, tlen); n = pg_mbstrlen_with_len(target, tlen);
......
...@@ -16,6 +16,24 @@ ...@@ -16,6 +16,24 @@
#include "parser/parse_node.h" #include "parser/parse_node.h"
/*
* Support for fuzzily matching column.
*
* This is for building diagnostic messages, where non-exact matching
* attributes are suggested to the user. The struct's fields may be facets of
* a particular RTE, or of an entire range table, depending on context.
*/
typedef struct
{
int distance; /* Weighted distance (lowest so far) */
RangeTblEntry *rfirst; /* RTE of first */
AttrNumber first; /* Closest attribute so far */
RangeTblEntry *rsecond; /* RTE of second */
AttrNumber second; /* Second closest attribute so far */
} FuzzyAttrMatchState;
extern RangeTblEntry *refnameRangeTblEntry(ParseState *pstate, extern RangeTblEntry *refnameRangeTblEntry(ParseState *pstate,
const char *schemaname, const char *schemaname,
const char *refname, const char *refname,
...@@ -35,7 +53,8 @@ extern RangeTblEntry *GetRTEByRangeTablePosn(ParseState *pstate, ...@@ -35,7 +53,8 @@ extern RangeTblEntry *GetRTEByRangeTablePosn(ParseState *pstate,
extern CommonTableExpr *GetCTEForRTE(ParseState *pstate, RangeTblEntry *rte, extern CommonTableExpr *GetCTEForRTE(ParseState *pstate, RangeTblEntry *rte,
int rtelevelsup); int rtelevelsup);
extern Node *scanRTEForColumn(ParseState *pstate, RangeTblEntry *rte, extern Node *scanRTEForColumn(ParseState *pstate, RangeTblEntry *rte,
char *colname, int location); char *colname, int location,
int fuzzy_rte_penalty, FuzzyAttrMatchState *fuzzystate);
extern Node *colNameToVar(ParseState *pstate, char *colname, bool localonly, extern Node *colNameToVar(ParseState *pstate, char *colname, bool localonly,
int location); int location);
extern void markVarForSelectPriv(ParseState *pstate, Var *var, extern void markVarForSelectPriv(ParseState *pstate, Var *var,
......
...@@ -536,6 +536,7 @@ create table atacc1 ( test int ); ...@@ -536,6 +536,7 @@ create table atacc1 ( test int );
-- add a check constraint (fails) -- add a check constraint (fails)
alter table atacc1 add constraint atacc_test1 check (test1>3); alter table atacc1 add constraint atacc_test1 check (test1>3);
ERROR: column "test1" does not exist ERROR: column "test1" does not exist
HINT: Perhaps you meant to reference the column "atacc1"."test".
drop table atacc1; drop table atacc1;
-- something a little more complicated -- something a little more complicated
create table atacc1 ( test int, test2 int, test3 int); create table atacc1 ( test int, test2 int, test3 int);
...@@ -1342,6 +1343,7 @@ select f1 from c1; ...@@ -1342,6 +1343,7 @@ select f1 from c1;
ERROR: column "f1" does not exist ERROR: column "f1" does not exist
LINE 1: select f1 from c1; LINE 1: select f1 from c1;
^ ^
HINT: Perhaps you meant to reference the column "c1"."f2".
drop table p1 cascade; drop table p1 cascade;
NOTICE: drop cascades to table c1 NOTICE: drop cascades to table c1
create table p1 (f1 int, f2 int); create table p1 (f1 int, f2 int);
...@@ -1355,6 +1357,7 @@ select f1 from c1; ...@@ -1355,6 +1357,7 @@ select f1 from c1;
ERROR: column "f1" does not exist ERROR: column "f1" does not exist
LINE 1: select f1 from c1; LINE 1: select f1 from c1;
^ ^
HINT: Perhaps you meant to reference the column "c1"."f2".
drop table p1 cascade; drop table p1 cascade;
NOTICE: drop cascades to table c1 NOTICE: drop cascades to table c1
create table p1 (f1 int, f2 int); create table p1 (f1 int, f2 int);
......
...@@ -2222,6 +2222,12 @@ select * from t1 left join t2 on (t1.a = t2.a); ...@@ -2222,6 +2222,12 @@ select * from t1 left join t2 on (t1.a = t2.a);
200 | 1000 | 200 | 2001 200 | 1000 | 200 | 2001
(5 rows) (5 rows)
-- Test matching of column name with wrong alias
select t1.x from t1 join t3 on (t1.a = t3.x);
ERROR: column t1.x does not exist
LINE 1: select t1.x from t1 join t3 on (t1.a = t3.x);
^
HINT: Perhaps you meant to reference the column "t3"."x".
-- --
-- regression test for 8.1 merge right join bug -- regression test for 8.1 merge right join bug
-- --
...@@ -3433,6 +3439,38 @@ select * from ...@@ -3433,6 +3439,38 @@ select * from
----+----+----+---- ----+----+----+----
(0 rows) (0 rows)
--
-- Test hints given on incorrect column references are useful
--
select t1.uunique1 from
tenk1 t1 join tenk2 t2 on t1.two = t2.two; -- error, prefer "t1" suggestipn
ERROR: column t1.uunique1 does not exist
LINE 1: select t1.uunique1 from
^
HINT: Perhaps you meant to reference the column "t1"."unique1".
select t2.uunique1 from
tenk1 t1 join tenk2 t2 on t1.two = t2.two; -- error, prefer "t2" suggestion
ERROR: column t2.uunique1 does not exist
LINE 1: select t2.uunique1 from
^
HINT: Perhaps you meant to reference the column "t2"."unique1".
select uunique1 from
tenk1 t1 join tenk2 t2 on t1.two = t2.two; -- error, suggest both at once
ERROR: column "uunique1" does not exist
LINE 1: select uunique1 from
^
HINT: Perhaps you meant to reference the column "t1"."unique1" or the column "t2"."unique1".
--
-- Take care to reference the correct RTE
--
select atts.relid::regclass, s.* from pg_stats s join
pg_attribute a on s.attname = a.attname and s.tablename =
a.attrelid::regclass::text join (select unnest(indkey) attnum,
indexrelid from pg_index i) atts on atts.attnum = a.attnum where
schemaname != 'pg_catalog';
ERROR: column atts.relid does not exist
LINE 1: select atts.relid::regclass, s.* from pg_stats s join
^
-- --
-- Test LATERAL -- Test LATERAL
-- --
......
...@@ -397,6 +397,10 @@ insert into t2a values (200, 2001); ...@@ -397,6 +397,10 @@ insert into t2a values (200, 2001);
select * from t1 left join t2 on (t1.a = t2.a); select * from t1 left join t2 on (t1.a = t2.a);
-- Test matching of column name with wrong alias
select t1.x from t1 join t3 on (t1.a = t3.x);
-- --
-- regression test for 8.1 merge right join bug -- regression test for 8.1 merge right join bug
-- --
...@@ -1060,6 +1064,26 @@ select * from ...@@ -1060,6 +1064,26 @@ select * from
int8_tbl x join (int4_tbl x cross join int4_tbl y(ff)) j on q1 = f1; -- ok int8_tbl x join (int4_tbl x cross join int4_tbl y(ff)) j on q1 = f1; -- ok
-- --
-- Test hints given on incorrect column references are useful
--
select t1.uunique1 from
tenk1 t1 join tenk2 t2 on t1.two = t2.two; -- error, prefer "t1" suggestipn
select t2.uunique1 from
tenk1 t1 join tenk2 t2 on t1.two = t2.two; -- error, prefer "t2" suggestion
select uunique1 from
tenk1 t1 join tenk2 t2 on t1.two = t2.two; -- error, suggest both at once
--
-- Take care to reference the correct RTE
--
select atts.relid::regclass, s.* from pg_stats s join
pg_attribute a on s.attname = a.attname and s.tablename =
a.attrelid::regclass::text join (select unnest(indkey) attnum,
indexrelid from pg_index i) atts on atts.attnum = a.attnum where
schemaname != 'pg_catalog';
--
-- Test LATERAL -- Test LATERAL
-- --
......
Markdown is supported
0% or
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment