diff --git a/mysql-test/r/select.result b/mysql-test/r/select.result
index 0d5c1aed48552f9c1ceb0b4c2c162fe897eaed62..24c890395662b8902eb3279d0001f0b8d13fa257 100644
--- a/mysql-test/r/select.result
+++ b/mysql-test/r/select.result
@@ -2897,3 +2897,18 @@ select * from t1 natural join t2 where a = 'b';
 a
 b
 drop table t1, t2;
+CREATE TABLE t1 (`id` TINYINT);
+CREATE TABLE t2 (`id` TINYINT);
+CREATE TABLE t3 (`id` TINYINT);
+INSERT INTO t1 VALUES (1),(2),(3);
+INSERT INTO t2 VALUES (2);
+INSERT INTO t3 VALUES (3);
+SELECT t1.id,t3.id FROM t1 JOIN t2 ON (t2.id=t1.id) LEFT JOIN t3 USING (id);
+ERROR 23000: Column 'id' in from clause is ambiguous
+SELECT t1.id,t3.id FROM t1 JOIN t2 ON (t2.notacolumn=t1.id) LEFT JOIN t3 USING (id);
+ERROR 23000: Column 'id' in from clause is ambiguous
+SELECT id,t3.id FROM t1 JOIN t2 ON (t2.id=t1.id) LEFT JOIN t3 USING (id);
+ERROR 23000: Column 'id' in from clause is ambiguous
+SELECT id,t3.id FROM (t1 JOIN t2 ON (t2.id=t1.id)) LEFT JOIN t3 USING (id);
+ERROR 23000: Column 'id' in from clause is ambiguous
+drop table t1, t2, t3;
diff --git a/mysql-test/t/select.test b/mysql-test/t/select.test
index fad01ac9acf938ed64fe6a01e75f89ce78fd932f..62687a869b71cbb204d6c22839b6eead2a739538 100644
--- a/mysql-test/t/select.test
+++ b/mysql-test/t/select.test
@@ -2465,3 +2465,25 @@ insert into t2 values ('b'),('c'),('d');
 select a from t1 natural join t2;
 select * from t1 natural join t2 where a = 'b';
 drop table t1, t2;
+
+#
+# Bug #12977 Compare table names with qualifying field tables only
+# for base tables, search all nested join operands of natural joins.
+#
+
+CREATE TABLE t1 (`id` TINYINT);
+CREATE TABLE t2 (`id` TINYINT);
+CREATE TABLE t3 (`id` TINYINT);
+INSERT INTO t1 VALUES (1),(2),(3);
+INSERT INTO t2 VALUES (2);
+INSERT INTO t3 VALUES (3);
+-- error 1052
+SELECT t1.id,t3.id FROM t1 JOIN t2 ON (t2.id=t1.id) LEFT JOIN t3 USING (id);
+-- error 1052
+SELECT t1.id,t3.id FROM t1 JOIN t2 ON (t2.notacolumn=t1.id) LEFT JOIN t3 USING (id);
+-- error 1052
+SELECT id,t3.id FROM t1 JOIN t2 ON (t2.id=t1.id) LEFT JOIN t3 USING (id);
+-- error 1052
+SELECT id,t3.id FROM (t1 JOIN t2 ON (t2.id=t1.id)) LEFT JOIN t3 USING (id);
+
+drop table t1, t2, t3;
diff --git a/sql/sql_base.cc b/sql/sql_base.cc
index 7025568a1c8b61115be4559004184f093157ba63..07c5896dd2e8b28394511695c73b60b13b8a1c33 100644
--- a/sql/sql_base.cc
+++ b/sql/sql_base.cc
@@ -2877,14 +2877,15 @@ find_field_in_table_ref(THD *thd, TABLE_LIST *table_list,
   /*
     Check that the table and database that qualify the current field name
     are the same as the table we are going to search for the field.
-    This is done differently for NATURAL/USING joins because there we can't
-    simply compare the qualifying table and database names with the ones of
+    This is done differently for NATURAL/USING joins or nested joins that
+    are operands of NATURAL/USING joins because there we can't simply
+    compare the qualifying table and database names with the ones of
     'table_list' because each field in such a join may originate from a
     different table.
     TODO: Ensure that table_name, db_name and tables->db always points to
           something !
   */
-  if (!table_list->is_natural_join &&
+  if (!(table_list->nested_join && table_list->join_columns) &&
       table_name && table_name[0] &&
       (my_strcasecmp(table_alias_charset, table_list->alias, table_name) ||
        (db_name && db_name[0] && table_list->db && table_list->db[0] &&
@@ -2899,8 +2900,13 @@ find_field_in_table_ref(THD *thd, TABLE_LIST *table_list,
                                  register_tree_change)))
       *actual_table= table_list;
   }
-  else if (table_list->is_natural_join)
+  else if (table_list->nested_join && table_list->join_columns)
   {
+    /*
+      If this is a NATURAL/USING join, or an operand of such join which is a
+      join itself, and the field name is qualified, then search for the field
+      in the operands of the join.
+    */
     if (table_name && table_name[0])
     {
       /*
@@ -2922,7 +2928,9 @@ find_field_in_table_ref(THD *thd, TABLE_LIST *table_list,
     }
     /*
       Non-qualified field, search directly in the result columns of the
-      natural join.
+      natural join. The condition of the outer IF is true for the top-most
+      natural join, thus if the field is not qualified, we will search
+      directly the top-most NATURAL/USING join.
     */
     fld= find_field_in_natural_join(thd, table_list, name, length, ref,
                                     /* TIMOUR_TODO: check this with Sanja */
@@ -3528,10 +3536,16 @@ mark_common_columns(THD *thd, TABLE_LIST *table_ref_1, TABLE_LIST *table_ref_2,
       if (add_columns && is_created_2)
         table_ref_2->join_columns->push_back(cur_nj_col_2);
 
-      /* Compare the two columns and check for duplicate common fields. */
+      /*
+        Compare the two columns and check for duplicate common fields.
+        A common field is duplicate either if it was already found in
+        table_ref_2 (then found == TRUE), or if a field in table_ref_2
+        was already matched by some previous field in table_ref_1
+        (then cur_nj_col_2->is_common == TRUE).
+      */
       if (!my_strcasecmp(system_charset_info, field_name_1, cur_field_name_2))
       {
-        if (found)
+        if (found || cur_nj_col_2->is_common)
         {
           my_error(ER_NON_UNIQ_ERROR, MYF(0), field_name_1, thd->where);
           goto err;