Skip to content

Commit

Permalink
MySQL compatible order by clause rules (#20368)
Browse files Browse the repository at this point in the history
兼容Mysql的order by子句;
1. order by子句在检索 排序键时,应当从所在查询子句的project list列表中查找,如果没有就从表中查找
2. project list列表中可以存在同名的投影列(有别名就是别名,没有别名就列名或者表达式)
3. 但是order by子句中引用的排序键不允许在project list列表重复,如果没有出现在project list就要在表中查找,如果仍然有重名,就要报错, 即不能有歧义
mo在投影列表中,只要有一个列使用了别名,都会从别名中查找排序键

注意:
projectList是第一级,先在projectList中查找,看能否找到且不重复,如果重复,则报错,注意:projectlist的别名和projectList属于同一级别,如果找不到则从表中查找,看能否找到且不重复,如果重复,则报错

Approved by: @badboynt1, @ouyuanning, @aunjgr, @heni02
  • Loading branch information
qingxinhome authored Nov 27, 2024
1 parent 7bdac32 commit 8cb120e
Show file tree
Hide file tree
Showing 7 changed files with 338 additions and 2 deletions.
1 change: 1 addition & 0 deletions pkg/sql/plan/bind_context.go
Original file line number Diff line number Diff line change
Expand Up @@ -33,6 +33,7 @@ func NewBindContext(builder *QueryBuilder, parent *BindContext) *BindContext {
windowByAst: make(map[string]int32),
timeByAst: make(map[string]int32),
aliasMap: make(map[string]*aliasItem),
aliasFrequency: make(map[string]int),
bindingByTag: make(map[int32]*Binding),
bindingByTable: make(map[string]*Binding),
bindingByCol: make(map[string]*Binding),
Expand Down
53 changes: 53 additions & 0 deletions pkg/sql/plan/order_binder.go
Original file line number Diff line number Diff line change
Expand Up @@ -29,7 +29,20 @@ func NewOrderBinder(projectionBinder *ProjectionBinder, selectList tree.SelectEx

func (b *OrderBinder) BindExpr(astExpr tree.Expr) (*plan.Expr, error) {
if colRef, ok := astExpr.(*tree.UnresolvedName); ok && colRef.NumParts == 1 {
if frequency, ok := b.ctx.aliasFrequency[colRef.ColName()]; ok && frequency > 1 {
return nil, moerr.NewInvalidInputf(b.GetContext(), "Column '%s' in order clause is ambiguous", colRef.ColName())
}

if selectItem, ok := b.ctx.aliasMap[colRef.ColName()]; ok {
for _, selectField := range b.ctx.projectByAst {
if selectField.aliasName != "" {
continue
}
if projectField, ok1 := selectField.ast.(*tree.UnresolvedName); ok1 && projectField.ColName() == colRef.ColName() {
return nil, moerr.NewInvalidInputf(b.GetContext(), "Column '%s' in order clause is ambiguous", colRef.ColName())
}
}

return &plan.Expr{
Typ: b.ctx.projects[selectItem.idx].Typ,
Expr: &plan.Expr_Col{
Expand All @@ -39,6 +52,46 @@ func (b *OrderBinder) BindExpr(astExpr tree.Expr) (*plan.Expr, error) {
},
},
}, nil
} else {
var matchedFields []int32 // SelectField index used to record matches
var matchedExpr *plan.Expr // Used to save matched expr

for _, selectField := range b.ctx.projectByAst {
if selectField.aliasName != "" {
if selectField.aliasName == colRef.ColName() {
// Record the selectField index that matches
matchedFields = append(matchedFields, selectField.pos)
// Save matching expr
matchedExpr = b.ctx.projects[selectField.pos]
} else {
continue
}
} else if projectField, ok1 := selectField.ast.(*tree.UnresolvedName); ok1 && projectField.ColName() == colRef.ColName() {
// Record the selectField index that matches
matchedFields = append(matchedFields, selectField.pos)
// Save matching expr
matchedExpr = &plan.Expr{
Typ: b.ctx.projects[selectField.pos].Typ,
Expr: &plan.Expr_Col{
Col: &plan.ColRef{
RelPos: b.ctx.projectTag,
ColPos: selectField.pos,
},
},
}
continue
}
}

// If multiple selectFields are matched, an error occurs
if len(matchedFields) > 1 {
return nil, moerr.NewInvalidInputf(b.GetContext(), "Column '%s' in order clause is ambiguous", colRef.ColName())
}

// If there is only one matching expr, return that expr
if matchedExpr != nil {
return matchedExpr, nil
}
}
}

Expand Down
13 changes: 13 additions & 0 deletions pkg/sql/plan/query_builder.go
Original file line number Diff line number Diff line change
Expand Up @@ -24,6 +24,7 @@ import (
"time"

"github.com/google/uuid"

"github.com/matrixorigin/matrixone/pkg/catalog"
"github.com/matrixorigin/matrixone/pkg/common/moerr"
"github.com/matrixorigin/matrixone/pkg/container/types"
Expand Down Expand Up @@ -2178,6 +2179,7 @@ func (builder *QueryBuilder) buildUnion(stmt *tree.UnionClause, astOrderBy tree.
ctx.aliasMap[v] = &aliasItem{
idx: int32(i),
}
ctx.aliasFrequency[v]++
builder.nameByColRef[[2]int32{ctx.projectTag, int32(i)}] = v
}
for i, expr := range firstSelectProjectNode.ProjectList {
Expand Down Expand Up @@ -2831,7 +2833,18 @@ func (builder *QueryBuilder) bindSelect(stmt *tree.Select, ctx *BindContext, isR
idx: int32(i),
astExpr: selectList[i].Expr,
}
ctx.aliasFrequency[selectList[i].As.Compare()]++
}

field := SelectField{
ast: selectList[i].Expr,
pos: int32(i),
}

if selectList[i].As != nil && !selectList[i].As.Empty() {
field.aliasName = selectList[i].As.Compare()
}
ctx.projectByAst = append(ctx.projectByAst, field)
}

if astTimeWindow != nil {
Expand Down
12 changes: 11 additions & 1 deletion pkg/sql/plan/types.go
Original file line number Diff line number Diff line change
Expand Up @@ -270,9 +270,12 @@ type BindContext struct {
projectByExpr map[string]int32
timeByAst map[string]int32

projectByAst []SelectField

timeAsts []tree.Expr

aliasMap map[string]*aliasItem
aliasMap map[string]*aliasItem
aliasFrequency map[string]int

bindings []*Binding
bindingByTag map[int32]*Binding //rel_pos
Expand Down Expand Up @@ -303,6 +306,13 @@ type BindContext struct {
groupingFlag []bool
}

type SelectField struct {
ast tree.Expr
// AsName is alias name for Expr
aliasName string
pos int32
}

type NameTuple struct {
table string
col string
Expand Down
160 changes: 160 additions & 0 deletions test/distributed/cases/dml/select/order_by_clause.result
Original file line number Diff line number Diff line change
@@ -0,0 +1,160 @@
DROP TABLE IF EXISTS dept;
create table dept(
deptno int unsigned auto_increment COMMENT '部门编号',
dname varchar(15) COMMENT '部门名称',
loc varchar(50) COMMENT '部门所在位置',
primary key(deptno)
) COMMENT='部门表';
INSERT INTO dept VALUES (10,'ACCOUNTING','NEW YORK');
INSERT INTO dept VALUES (20,'RESEARCH','DALLAS');
INSERT INTO dept VALUES (30,'SALES','CHICAGO');
INSERT INTO dept VALUES (40,'OPERATIONS','BOSTON');
DROP TABLE IF EXISTS emp;
create table emp(
empno int unsigned auto_increment COMMENT '雇员编号',
ename varchar(15) COMMENT '雇员姓名',
job varchar(10) COMMENT '雇员职位',
mgr int unsigned COMMENT '雇员对应的领导的编号',
hiredate date COMMENT '雇员的雇佣日期',
sal decimal(7,2) COMMENT '雇员的基本工资',
comm decimal(7,2) COMMENT '奖金',
deptno int unsigned COMMENT '所在部门',
primary key(empno)
) COMMENT='雇员表';
INSERT INTO emp VALUES (7369,'SMITH','CLERK',7902,'1980-12-17',800,NULL,20);
INSERT INTO emp VALUES (7499,'ALLEN','SALESMAN',7698,'1981-02-20',1600,300,30);
INSERT INTO emp VALUES (7521,'WARD','SALESMAN',7698,'1981-02-22',1250,500,30);
INSERT INTO emp VALUES (7566,'JONES','MANAGER',7839,'1981-04-02',2975,NULL,20);
INSERT INTO emp VALUES (7654,'MARTIN','SALESMAN',7698,'1981-09-28',1250,1400,30);
INSERT INTO emp VALUES (7698,'BLAKE','MANAGER',7839,'1981-05-01',2850,NULL,30);
INSERT INTO emp VALUES (7782,'CLARK','MANAGER',7839,'1981-06-09',2450,NULL,10);
INSERT INTO emp VALUES (7788,'SCOTT','ANALYST',7566,'0087-07-13',3000,NULL,20);
INSERT INTO emp VALUES (7839,'KING','PRESIDENT',NULL,'1981-11-17',5000,NULL,10);
INSERT INTO emp VALUES (7844,'TURNER','SALESMAN',7698,'1981-09-08',1500,0,30);
INSERT INTO emp VALUES (7876,'ADAMS','CLERK',7788,'0087-07-13',1100,NULL,20);
INSERT INTO emp VALUES (7900,'JAMES','CLERK',7698,'1981-12-03',950,NULL,30);
INSERT INTO emp VALUES (7902,'FORD','ANALYST',7566,'1981-12-03',3000,NULL,20);
INSERT INTO emp VALUES (7934,'MILLER','CLERK',7782,'1982-01-23',1300,NULL,10);
select t1.*, t2.deptno as deptno from emp t1 left join dept t2 on t1.deptno = t2.deptno order by deptno;
invalid input: Column 'deptno' in order clause is ambiguous
select t1.*, t2.deptno from emp t1 left join dept t2 on t1.deptno = t2.deptno order by deptno;
invalid input: Column 'deptno' in order clause is ambiguous
mysql> select empno X1, ename X1, sal X1 from emp where sal > 200 order by X1;
SQL parser error: You have an error in your SQL syntax; check the manual that corresponds to your MatrixOne server version for the right syntax to use. syntax error at line 1 column 5 near "mysql> select empno X1, ename X1, sal X1 from emp where sal > 200 order by X1;";
select t2.dname, t1.* from emp t1 left join dept t2 on t1.deptno = t2.deptno order by deptno;
dname empno ename job mgr hiredate sal comm deptno
ACCOUNTING 7782 CLARK MANAGER 7839 1981-06-09 2450.00 null 10
ACCOUNTING 7934 MILLER CLERK 7782 1982-01-23 1300.00 null 10
ACCOUNTING 7839 KING PRESIDENT null 1981-11-17 5000.00 null 10
RESEARCH 7566 JONES MANAGER 7839 1981-04-02 2975.00 null 20
RESEARCH 7369 SMITH CLERK 7902 1980-12-17 800.00 null 20
RESEARCH 7788 SCOTT ANALYST 7566 0087-07-13 3000.00 null 20
RESEARCH 7876 ADAMS CLERK 7788 0087-07-13 1100.00 null 20
RESEARCH 7902 FORD ANALYST 7566 1981-12-03 3000.00 null 20
SALES 7654 MARTIN SALESMAN 7698 1981-09-28 1250.00 1400.00 30
SALES 7698 BLAKE MANAGER 7839 1981-05-01 2850.00 null 30
SALES 7521 WARD SALESMAN 7698 1981-02-22 1250.00 500.00 30
SALES 7844 TURNER SALESMAN 7698 1981-09-08 1500.00 0.00 30
SALES 7900 JAMES CLERK 7698 1981-12-03 950.00 null 30
SALES 7499 ALLEN SALESMAN 7698 1981-02-20 1600.00 300.00 30
select t2.dname as deptname, t1.* from emp t1 left join dept t2 on t1.deptno = t2.deptno order by deptno;
deptname empno ename job mgr hiredate sal comm deptno
ACCOUNTING 7782 CLARK MANAGER 7839 1981-06-09 2450.00 null 10
ACCOUNTING 7934 MILLER CLERK 7782 1982-01-23 1300.00 null 10
ACCOUNTING 7839 KING PRESIDENT null 1981-11-17 5000.00 null 10
RESEARCH 7566 JONES MANAGER 7839 1981-04-02 2975.00 null 20
RESEARCH 7369 SMITH CLERK 7902 1980-12-17 800.00 null 20
RESEARCH 7788 SCOTT ANALYST 7566 0087-07-13 3000.00 null 20
RESEARCH 7876 ADAMS CLERK 7788 0087-07-13 1100.00 null 20
RESEARCH 7902 FORD ANALYST 7566 1981-12-03 3000.00 null 20
SALES 7654 MARTIN SALESMAN 7698 1981-09-28 1250.00 1400.00 30
SALES 7698 BLAKE MANAGER 7839 1981-05-01 2850.00 null 30
SALES 7521 WARD SALESMAN 7698 1981-02-22 1250.00 500.00 30
SALES 7844 TURNER SALESMAN 7698 1981-09-08 1500.00 0.00 30
SALES 7900 JAMES CLERK 7698 1981-12-03 950.00 null 30
SALES 7499 ALLEN SALESMAN 7698 1981-02-20 1600.00 300.00 30
select t2.dname as deptname, t1.* from emp t1 left join dept t2 on t1.deptno = t2.deptno where '1' = '1' order by deptno;
deptname empno ename job mgr hiredate sal comm deptno
ACCOUNTING 7782 CLARK MANAGER 7839 1981-06-09 2450.00 null 10
ACCOUNTING 7934 MILLER CLERK 7782 1982-01-23 1300.00 null 10
ACCOUNTING 7839 KING PRESIDENT null 1981-11-17 5000.00 null 10
RESEARCH 7566 JONES MANAGER 7839 1981-04-02 2975.00 null 20
RESEARCH 7369 SMITH CLERK 7902 1980-12-17 800.00 null 20
RESEARCH 7788 SCOTT ANALYST 7566 0087-07-13 3000.00 null 20
RESEARCH 7876 ADAMS CLERK 7788 0087-07-13 1100.00 null 20
RESEARCH 7902 FORD ANALYST 7566 1981-12-03 3000.00 null 20
SALES 7654 MARTIN SALESMAN 7698 1981-09-28 1250.00 1400.00 30
SALES 7698 BLAKE MANAGER 7839 1981-05-01 2850.00 null 30
SALES 7521 WARD SALESMAN 7698 1981-02-22 1250.00 500.00 30
SALES 7844 TURNER SALESMAN 7698 1981-09-08 1500.00 0.00 30
SALES 7900 JAMES CLERK 7698 1981-12-03 950.00 null 30
SALES 7499 ALLEN SALESMAN 7698 1981-02-20 1600.00 300.00 30
select t2.dname as deptname, t1.* from emp t1 left join dept t2 on t1.deptno = t2.deptno where '1' = '1' order by deptno, empno;
deptname empno ename job mgr hiredate sal comm deptno
ACCOUNTING 7782 CLARK MANAGER 7839 1981-06-09 2450.00 null 10
ACCOUNTING 7839 KING PRESIDENT null 1981-11-17 5000.00 null 10
ACCOUNTING 7934 MILLER CLERK 7782 1982-01-23 1300.00 null 10
RESEARCH 7369 SMITH CLERK 7902 1980-12-17 800.00 null 20
RESEARCH 7566 JONES MANAGER 7839 1981-04-02 2975.00 null 20
RESEARCH 7788 SCOTT ANALYST 7566 0087-07-13 3000.00 null 20
RESEARCH 7876 ADAMS CLERK 7788 0087-07-13 1100.00 null 20
RESEARCH 7902 FORD ANALYST 7566 1981-12-03 3000.00 null 20
SALES 7499 ALLEN SALESMAN 7698 1981-02-20 1600.00 300.00 30
SALES 7521 WARD SALESMAN 7698 1981-02-22 1250.00 500.00 30
SALES 7654 MARTIN SALESMAN 7698 1981-09-28 1250.00 1400.00 30
SALES 7698 BLAKE MANAGER 7839 1981-05-01 2850.00 null 30
SALES 7844 TURNER SALESMAN 7698 1981-09-08 1500.00 0.00 30
SALES 7900 JAMES CLERK 7698 1981-12-03 950.00 null 30
select t2.dname as deptname, t1.*
from emp t1 left join dept t2 on t1.deptno = t2.deptno where '1' = '1'
group by t1.ename
order by deptno;
SQL syntax error: column "t2.dname" must appear in the GROUP BY clause or be used in an aggregate function
select t1.*, t2.loc, t2.deptno as deptno from emp t1 left join dept t2 on t1.deptno = t2.deptno order by deptno;
invalid input: Column 'deptno' in order clause is ambiguous
select t1.ename, t2.loc, t2.deptno as deptno from emp t1 left join dept t2 on t1.deptno = t2.deptno order by deptno;
ename loc deptno
CLARK NEW YORK 10
MILLER NEW YORK 10
KING NEW YORK 10
JONES DALLAS 20
SMITH DALLAS 20
SCOTT DALLAS 20
ADAMS DALLAS 20
FORD DALLAS 20
MARTIN CHICAGO 30
BLAKE CHICAGO 30
WARD CHICAGO 30
TURNER CHICAGO 30
JAMES CHICAGO 30
ALLEN CHICAGO 30
select t1.ename, t2.loc from emp t1 left join dept t2 on t1.deptno = t2.deptno order by deptno;
invalid input: ambiguouse column reference to 'deptno'
select t1.ename, t2.loc, t2.deptno as deptno from emp t1 left join dept t2 on t1.deptno = t2.deptno order by deptno+33;
ename loc deptno
CLARK NEW YORK 10
MILLER NEW YORK 10
KING NEW YORK 10
JONES DALLAS 20
SMITH DALLAS 20
SCOTT DALLAS 20
ADAMS DALLAS 20
FORD DALLAS 20
MARTIN CHICAGO 30
BLAKE CHICAGO 30
WARD CHICAGO 30
TURNER CHICAGO 30
JAMES CHICAGO 30
ALLEN CHICAGO 30
select t1.ename, t2.loc from emp t1 left join dept t2 on t1.deptno = t2.deptno order by deptno;
invalid input: ambiguouse column reference to 'deptno'
select ename, (select ename from emp i1 where i1.empno = emp.mgr order by 1 limit 1) as ename from emp order by ename;
invalid input: Column 'ename' in order clause is ambiguous
select empno, (select ename from emp i1 where i1.empno = emp.mgr order by 1 limit 1) as ename, ename from emp order by ename;
invalid input: Column 'ename' in order clause is ambiguous
select empno, 20 as empno from emp order by empno;
invalid input: Column 'empno' in order clause is ambiguous
select empno, space(50) as empno from emp order by empno;
invalid input: Column 'empno' in order clause is ambiguous
drop table if exists dept;
drop table if exists emp;
99 changes: 99 additions & 0 deletions test/distributed/cases/dml/select/order_by_clause.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,99 @@
DROP TABLE IF EXISTS dept;
create table dept(
deptno int unsigned auto_increment COMMENT '部门编号',
dname varchar(15) COMMENT '部门名称',
loc varchar(50) COMMENT '部门所在位置',
primary key(deptno)
) COMMENT='部门表';

INSERT INTO dept VALUES (10,'ACCOUNTING','NEW YORK');
INSERT INTO dept VALUES (20,'RESEARCH','DALLAS');
INSERT INTO dept VALUES (30,'SALES','CHICAGO');
INSERT INTO dept VALUES (40,'OPERATIONS','BOSTON');

DROP TABLE IF EXISTS emp;
create table emp(
empno int unsigned auto_increment COMMENT '雇员编号',
ename varchar(15) COMMENT '雇员姓名',
job varchar(10) COMMENT '雇员职位',
mgr int unsigned COMMENT '雇员对应的领导的编号',
hiredate date COMMENT '雇员的雇佣日期',
sal decimal(7,2) COMMENT '雇员的基本工资',
comm decimal(7,2) COMMENT '奖金',
deptno int unsigned COMMENT '所在部门',
primary key(empno)
) COMMENT='雇员表';

INSERT INTO emp VALUES (7369,'SMITH','CLERK',7902,'1980-12-17',800,NULL,20);
INSERT INTO emp VALUES (7499,'ALLEN','SALESMAN',7698,'1981-02-20',1600,300,30);
INSERT INTO emp VALUES (7521,'WARD','SALESMAN',7698,'1981-02-22',1250,500,30);
INSERT INTO emp VALUES (7566,'JONES','MANAGER',7839,'1981-04-02',2975,NULL,20);
INSERT INTO emp VALUES (7654,'MARTIN','SALESMAN',7698,'1981-09-28',1250,1400,30);
INSERT INTO emp VALUES (7698,'BLAKE','MANAGER',7839,'1981-05-01',2850,NULL,30);
INSERT INTO emp VALUES (7782,'CLARK','MANAGER',7839,'1981-06-09',2450,NULL,10);
INSERT INTO emp VALUES (7788,'SCOTT','ANALYST',7566,'0087-07-13',3000,NULL,20);
INSERT INTO emp VALUES (7839,'KING','PRESIDENT',NULL,'1981-11-17',5000,NULL,10);
INSERT INTO emp VALUES (7844,'TURNER','SALESMAN',7698,'1981-09-08',1500,0,30);
INSERT INTO emp VALUES (7876,'ADAMS','CLERK',7788,'0087-07-13',1100,NULL,20);
INSERT INTO emp VALUES (7900,'JAMES','CLERK',7698,'1981-12-03',950,NULL,30);
INSERT INTO emp VALUES (7902,'FORD','ANALYST',7566,'1981-12-03',3000,NULL,20);
INSERT INTO emp VALUES (7934,'MILLER','CLERK',7782,'1982-01-23',1300,NULL,10);

--1.mysql:ERROR; mo: ERROR --ERROR 1052 (23000): Column 'deptno' in order clause is ambiguous
select t1.*, t2.deptno as deptno from emp t1 left join dept t2 on t1.deptno = t2.deptno order by deptno;

--2.mysql:ERROR; mo: ERROR --ERROR 1052 (23000): Column 'deptno' in order clause is ambiguous
select t1.*, t2.deptno from emp t1 left join dept t2 on t1.deptno = t2.deptno order by deptno;

--3.mysql:ERROR; mo: ERROR --ERROR 1052 (23000): Column 'X1' in order clause is ambiguous
mysql> select empno X1, ename X1, sal X1 from emp where sal > 200 order by X1;

--4.mysql:ok; mo: ok;
select t2.dname, t1.* from emp t1 left join dept t2 on t1.deptno = t2.deptno order by deptno;

--5.mysql:ok; mo: ok
select t2.dname as deptname, t1.* from emp t1 left join dept t2 on t1.deptno = t2.deptno order by deptno;

--6.mysql:ok; mo: ok
select t2.dname as deptname, t1.* from emp t1 left join dept t2 on t1.deptno = t2.deptno where '1' = '1' order by deptno;

--7.mysql:ok; mo: ok
select t2.dname as deptname, t1.* from emp t1 left join dept t2 on t1.deptno = t2.deptno where '1' = '1' order by deptno, empno;

--8.mysql:ok; mo: ok
select t2.dname as deptname, t1.*
from emp t1 left join dept t2 on t1.deptno = t2.deptno where '1' = '1'
group by t1.ename
order by deptno;

--9.mysql:ERROR; mo: ERROR
select t1.*, t2.loc, t2.deptno as deptno from emp t1 left join dept t2 on t1.deptno = t2.deptno order by deptno;

--10.mysql:ok; mo: ok
select t1.ename, t2.loc, t2.deptno as deptno from emp t1 left join dept t2 on t1.deptno = t2.deptno order by deptno;

--11. mysql:error; mo: error
select t1.ename, t2.loc from emp t1 left join dept t2 on t1.deptno = t2.deptno order by deptno;

--12. mysql: error, 别名不会参与order by表达式运算, mo: ok(bug)
select t1.ename, t2.loc, t2.deptno as deptno from emp t1 left join dept t2 on t1.deptno = t2.deptno order by deptno+33;

--13.mysql:error; mo: error
select t1.ename, t2.loc from emp t1 left join dept t2 on t1.deptno = t2.deptno order by deptno;

--14.mysql:ok, mo: error(bug,暂时选择报错)
-- mysql的别名是有作用域的, 通常selectList中子查询别名的优先级较高,即使主查询和子查询使用了相同的别名 ename,
-- 排序键冲突时MySQL会优先选择子查询别名,
select ename, (select ename from emp i1 where i1.empno = emp.mgr order by 1 limit 1) as ename from emp order by ename;

--15.mysql:ok, mo: error(bug,暂时选择报错) (同上)
select empno, (select ename from emp i1 where i1.empno = emp.mgr order by 1 limit 1) as ename, ename from emp order by ename;

--16.mysql: ok, mo: error(bug,暂时选择报错)
select empno, 20 as empno from emp order by empno;

--17..mysql: ok, mo: error(bug,暂时选择报错) (同上)
select empno, space(50) as empno from emp order by empno;

drop table if exists dept;
drop table if exists emp;
Loading

0 comments on commit 8cb120e

Please sign in to comment.