diff --git a/mysql-test/r/join_nested.result b/mysql-test/r/join_nested.result
index 6b7293d46bcdab81caa11ce6446b68ed58bd911b..faad969fcd1dc6cd359a88f4179fba95eab7bd3a 100644
--- a/mysql-test/r/join_nested.result
+++ b/mysql-test/r/join_nested.result
@@ -960,7 +960,7 @@ id	select_type	table	type	possible_keys	key	key_len	ref	rows	Extra
 1	SIMPLE	t2	ALL	NULL	NULL	NULL	NULL	3	Using where
 1	SIMPLE	t3	ALL	NULL	NULL	NULL	NULL	2	Using where
 1	SIMPLE	t4	ref	idx_b	idx_b	5	test.t2.b	2	Using where
-1	SIMPLE	t5	ALL	NULL	NULL	NULL	NULL	3	Using where
+1	SIMPLE	t5	ALL	idx_b	NULL	NULL	NULL	3	Using where
 1	SIMPLE	t7	ALL	NULL	NULL	NULL	NULL	2	Using where
 1	SIMPLE	t6	ALL	NULL	NULL	NULL	NULL	3	Using where
 1	SIMPLE	t8	ALL	NULL	NULL	NULL	NULL	2	Using where
@@ -1009,7 +1009,7 @@ id	select_type	table	type	possible_keys	key	key_len	ref	rows	Extra
 1	SIMPLE	t2	ALL	NULL	NULL	NULL	NULL	3	Using where
 1	SIMPLE	t3	ALL	NULL	NULL	NULL	NULL	2	Using where
 1	SIMPLE	t4	ref	idx_b	idx_b	5	test.t2.b	2	Using where
-1	SIMPLE	t5	ALL	NULL	NULL	NULL	NULL	3	Using where
+1	SIMPLE	t5	ALL	idx_b	NULL	NULL	NULL	3	Using where
 1	SIMPLE	t7	ALL	NULL	NULL	NULL	NULL	2	Using where
 1	SIMPLE	t6	ALL	NULL	NULL	NULL	NULL	3	Using where
 1	SIMPLE	t8	ref	idx_b	idx_b	5	test.t5.b	2	Using where
@@ -1059,7 +1059,7 @@ id	select_type	table	type	possible_keys	key	key_len	ref	rows	Extra
 1	SIMPLE	t2	ALL	NULL	NULL	NULL	NULL	3	Using where
 1	SIMPLE	t3	ALL	NULL	NULL	NULL	NULL	2	Using where
 1	SIMPLE	t4	ref	idx_b	idx_b	5	test.t2.b	2	Using where
-1	SIMPLE	t5	ALL	NULL	NULL	NULL	NULL	3	Using where
+1	SIMPLE	t5	ALL	idx_b	NULL	NULL	NULL	3	Using where
 1	SIMPLE	t7	ALL	NULL	NULL	NULL	NULL	2	Using where
 1	SIMPLE	t6	ALL	NULL	NULL	NULL	NULL	3	Using where
 1	SIMPLE	t8	ref	idx_b	idx_b	5	test.t5.b	2	Using where
@@ -1467,3 +1467,17 @@ id	select_type	table	type	possible_keys	key	key_len	ref	rows	Extra
 1	SIMPLE	t6	ref	a	a	5	test.t4.b	X	
 1	SIMPLE	t5	ref	a	a	5	test.t3.b	X	
 drop table t0, t1, t2, t3, t4, t5, t6, t7;
+create table t1 (a int);
+insert into t1 values (0),(1),(2),(3),(4),(5),(6),(7),(8),(9);
+create table t2 (a int, filler char(100), key(a));
+insert into t2 select A.a + 10*B.a, '' from t1 A, t1 B;
+create table t3 like t2;
+insert into t3 select * from t2;
+explain select * from t1 left join 
+(t2 left join t3 on (t2.a = t3.a)) 
+on (t1.a = t2.a);
+id	select_type	table	type	possible_keys	key	key_len	ref	rows	Extra
+1	SIMPLE	t1	ALL	NULL	NULL	NULL	NULL	10	
+1	SIMPLE	t2	ref	a	a	5	test.t1.a	1	
+1	SIMPLE	t3	ref	a	a	5	test.t2.a	1	
+drop table t1, t2, t3;
diff --git a/mysql-test/t/join_nested.test b/mysql-test/t/join_nested.test
index 9f23e2d0e2f1b03db27e8b8c8c84a92a869534fc..145edded486ae7a5f681e040a0ffe5f65f5db3e5 100644
--- a/mysql-test/t/join_nested.test
+++ b/mysql-test/t/join_nested.test
@@ -900,3 +900,17 @@ explain select * from t2 left join
    join t5 on t5.a=t3.b) on t3.a=t2.b;
 
 drop table t0, t1, t2, t3, t4, t5, t6, t7;
+
+# BUG#16393
+create table t1 (a int);
+insert into t1 values (0),(1),(2),(3),(4),(5),(6),(7),(8),(9);
+create table t2 (a int, filler char(100), key(a));
+insert into t2 select A.a + 10*B.a, '' from t1 A, t1 B;
+create table t3 like t2;
+insert into t3 select * from t2;
+
+explain select * from t1 left join 
+  (t2 left join t3 on (t2.a = t3.a)) 
+  on (t1.a = t2.a);
+drop table t1, t2, t3;
+
diff --git a/sql/sql_select.cc b/sql/sql_select.cc
index ab58fda8dea8d305f04d0dcc4b819fbf634ff32b..be255d1f790b2b22d18400720a0115710bdfad6f 100644
--- a/sql/sql_select.cc
+++ b/sql/sql_select.cc
@@ -2918,6 +2918,56 @@ sort_keyuse(KEYUSE *a,KEYUSE *b)
 }
 
 
+/*
+  Add to KEY_FIELD array all 'ref' access candidates within nested join
+
+  SYNPOSIS
+    add_key_fields_for_nj()
+      nested_join_table  IN     Nested join pseudo-table to process
+      end                INOUT  End of the key field array
+      and_level          INOUT  And-level
+
+  DESCRIPTION
+    This function populates KEY_FIELD array with entries generated from the 
+    ON condition of the given nested join, and does the same for nested joins 
+    contained within this nested join.
+
+  NOTES
+    We can add accesses to the tables that are direct children of this nested 
+    join (1), and are not inner tables w.r.t their neighbours (2).
+    
+    Example for #1 (outer brackets pair denotes nested join this function is 
+    invoked for):
+     ... LEFT JOIN (t1 LEFT JOIN (t2 ... ) ) ON cond
+    Example for #2:
+     ... LEFT JOIN (t1 LEFT JOIN t2 ) ON cond
+    In examples 1-2 for condition cond, we can add 'ref' access candidates to 
+    t1 only.
+    Example #3:
+     ... LEFT JOIN (t1, t2 LEFT JOIN t3 ON inner_cond) ON cond
+    Here we can add 'ref' access candidates for t1 and t2, but not for t3.
+*/
+
+static void add_key_fields_for_nj(TABLE_LIST *nested_join_table,
+                                  KEY_FIELD **end, uint *and_level)
+{
+  List_iterator<TABLE_LIST> li(nested_join_table->nested_join->join_list);
+  table_map tables= 0;
+  TABLE_LIST *table;
+  DBUG_ASSERT(nested_join_table->nested_join);
+
+  while ((table= li++))
+  {
+    if (table->nested_join)
+      add_key_fields_for_nj(table, end, and_level);
+    else
+      if (!table->on_expr)
+        tables |= table->table->map;
+  }
+  add_key_fields(end, and_level, nested_join_table->on_expr, tables);
+}
+
+
 /*
   Update keyuse array with all possible keys we can use to fetch rows
   
@@ -2982,23 +3032,21 @@ update_ref_and_keys(THD *thd, DYNAMIC_ARRAY *keyuse,JOIN_TAB *join_tab,
       into account as well.
     */ 
     if (*join_tab[i].on_expr_ref)
-    {
       add_key_fields(&end,&and_level,*join_tab[i].on_expr_ref,
 		     join_tab[i].table->map);
-    }
-    else 
+  }
+
+  /* Process ON conditions for the nested joins */
+  {
+    List_iterator<TABLE_LIST> li(*join_tab->join->join_list);
+    TABLE_LIST *table;
+    while ((table= li++))
     {
-      TABLE_LIST *tab= join_tab[i].table->pos_in_table_list;
-      TABLE_LIST *embedding= tab->embedding;
-      if (embedding)
-      {
-        NESTED_JOIN *nested_join= embedding->nested_join;
-        if (nested_join->join_list.head() == tab)
-          add_key_fields(&end, &and_level, embedding->on_expr,
-                         nested_join->used_tables);
-      }
+      if (table->nested_join)
+	add_key_fields_for_nj(table, &end, &and_level);
     }
   }
+
   /* fill keyuse with found key parts */
   for ( ; field != end ; field++)
     add_key_part(keyuse,field);