Skip to content

Commit

Permalink
*.: complete delete syntax radondb#713
Browse files Browse the repository at this point in the history
[summary]
1. complete single-table syntax, add delete options and parition.
2. add support to parse multi-table syntax.
3. add support to delete without where clause, like "delete from t1
limit 2"

[test case]
sqlparser/ast_test.go
sqlparser/parse_test.go
sqlparser/ast_test.go
src/planner/builder/expr_test.go
src/planner/delete_plan_test.go

[patch codecov]
sqlparser/ast.go 96.1%
sqlparser/ast_funcs.go 94.4%
src/planner/delete_plan.go  93.9%
src/planner/update_plan.go  95.1%
  • Loading branch information
hustjieke committed Dec 31, 2020
1 parent 3885e5a commit 27a46b3
Show file tree
Hide file tree
Showing 17 changed files with 4,109 additions and 3,288 deletions.
28 changes: 24 additions & 4 deletions docs/sql_statements/data_manipulation_statements.md
Original file line number Diff line number Diff line change
Expand Up @@ -12,20 +12,40 @@ Table of Contents

## DELETE Statement

`Syntax`
`Single-Table Syntax`
```
DELETE [LOW_PRIORITY] [QUICK] [IGNORE] FROM tbl_name [[AS] tbl_alias]
[PARTITION (partition_name [, partition_name] ...)]
[WHERE where_condition]
[ORDER BY ...]
[LIMIT row_count]
```

`Multiple-Table Syntax`
```
DELETE FROM tbl_name
DELETE [LOW_PRIORITY] [QUICK] [IGNORE]
tbl_name[.*] [, tbl_name[.*]] ...
FROM table_references
[WHERE where_condition]
DELETE [LOW_PRIORITY] [QUICK] [IGNORE]
FROM tbl_name[.*] [, tbl_name[.*]] ...
USING table_references
[WHERE where_condition]
```

``Instructions``
* Support distributed transactions to ensure that atomicity is removed across partitions
* *Does not support delete without WHERE condition*
* *Does not support clauses*
* *Does not partition feature*
* *Currently we support parse syntax 'delete with multitables',but the function does not implement yet*

`Example: `
```
mysql> DELETE FROM t1 WHERE id=1;
mysql> DELETE FROM t1 WHERE id=1 order by id limit 2;
Query OK, 2 rows affected (0.01 sec)
mysql> DELETE FROM t1;
Query OK, 2 rows affected (0.01 sec)
```

Expand Down
174 changes: 174 additions & 0 deletions intergration/radon-test/r/delete.result
Original file line number Diff line number Diff line change
@@ -0,0 +1,174 @@
create database if not exists integrate_test DEFAULT CHARSET=utf8;

drop table if exists integrate_test.t1, integrate_test.t2;


CREATE /*test hash*/ TABLE integrate_test.t1 (a tinyint(3) key, b tinyint(5));

INSERT INTO integrate_test.t1 VALUES (1,1);

INSERT LOW_PRIORITY INTO integrate_test.t1 VALUES (2,2);

INSERT INTO integrate_test.t1 VALUES (3,3);

DELETE from integrate_test.t1 where a=1 limit 1;

DELETE LOW_PRIORITY from integrate_test.t1 where a=2;

select * from integrate_test.t1;
a b
3 3

INSERT INTO integrate_test.t1 VALUES (1,1);

DELETE quick from integrate_test.t1;

select * from integrate_test.t1;

drop table integrate_test.t1;


create table integrate_test.t2 (
a bigint not null,
b bigint not null default 0,
c bigint not null default 0,
d bigint not null default 0,
e bigint not null default 0,
f bigint not null default 0,
g bigint not null default 0,
h bigint not null default 0,
i bigint not null default 0,
j bigint not null default 0,
primary key (a,b,c,d,e,f,g,h,i,j));

insert into integrate_test.t2 (a) values (2),(4),(6),(8),(10),(12),(14),(16),(18),(20),(22),(24),(26),(23);

delete from integrate_test.t2 where a=26;

select * from integrate_test.t2 order by a;
a b c d e f g h i j
2 0 0 0 0 0 0 0 0 0
4 0 0 0 0 0 0 0 0 0
6 0 0 0 0 0 0 0 0 0
8 0 0 0 0 0 0 0 0 0
10 0 0 0 0 0 0 0 0 0
12 0 0 0 0 0 0 0 0 0
14 0 0 0 0 0 0 0 0 0
16 0 0 0 0 0 0 0 0 0
18 0 0 0 0 0 0 0 0 0
20 0 0 0 0 0 0 0 0 0
22 0 0 0 0 0 0 0 0 0
23 0 0 0 0 0 0 0 0 0
24 0 0 0 0 0 0 0 0 0

drop table integrate_test.t2;

create table integrate_test.t1 (
a bigint not null,
b bigint not null default 0,
c bigint not null default 0,
d bigint not null default 0,
e bigint not null default 0,
f bigint not null default 0,
g bigint not null default 0,
h bigint not null default 0,
i bigint not null default 0,
j bigint not null default 0,
primary key (a,b,c,d,e,f,g,h,i,j));

insert into integrate_test.t1 (a) values (2),(4),(6),(8),(10),(12),(14),(16),(18),(20),(22),(24),(26),(23),(27);

delete from integrate_test.t1 where a=27;

select * from integrate_test.t1 order by a;
a b c d e f g h i j
2 0 0 0 0 0 0 0 0 0
4 0 0 0 0 0 0 0 0 0
6 0 0 0 0 0 0 0 0 0
8 0 0 0 0 0 0 0 0 0
10 0 0 0 0 0 0 0 0 0
12 0 0 0 0 0 0 0 0 0
14 0 0 0 0 0 0 0 0 0
16 0 0 0 0 0 0 0 0 0
18 0 0 0 0 0 0 0 0 0
20 0 0 0 0 0 0 0 0 0
22 0 0 0 0 0 0 0 0 0
23 0 0 0 0 0 0 0 0 0
24 0 0 0 0 0 0 0 0 0
26 0 0 0 0 0 0 0 0 0

drop table integrate_test.t1;


CREATE /*test error, column not exist*/ TABLE integrate_test.t1 (
`i` int(10) NOT NULL default '0',
`i2` int(10) NOT NULL default '0',
PRIMARY KEY (`i`)
);

DELETE FROM integrate_test.t1 WHERE post='1';
ERROR 1054 (42S22): Unknown column 'post' in 'where clause'

drop table integrate_test.t1;


create /*test global*/ table integrate_test.t2 (a bigint not null auto_increment primary key, b char(32)) global;

insert into integrate_test.t2 (a,b) values (1,'apple'), (2,'apple');

select * from integrate_test.t2;
a b
1 apple
2 apple

delete /*test unsupport, currently not support delete multitables*/ integrate_test.t2 from integrate_test.t2, integrate_test.t2 as t1 where integrate_test.t2.b = integrate_test.t1.b and integrate_test.t2.a > integrate_test.t1.a;
ERROR 1105 (HY000): unsupported: currently.not.support.multitables.in.delete

delete /*test unsupport, currently not support delete with partition*/ from integrate_test.t2 partition (p0) where a = 1;
ERROR 1105 (HY000): unsupported: currently.not.support.partitions.in.delete

DELETE /*test unsupport, currently not support delete with subquery*/ FROM integrate_test.t2 ORDER BY (SELECT x);
ERROR 1105 (HY000): unsupported: subqueries.in.delete

drop table integrate_test.t2;


CREATE TABLE integrate_test.t1(a INTEGER PRIMARY KEY) single;

INSERT INTO integrate_test.t1 VALUES(10),(20);

CREATE TABLE integrate_test.t2(b INTEGER key);

INSERT INTO integrate_test.t2 VALUES(10),(20);

DELETE /*test unsupport with join, not support delete with multitables*/ integrate_test.t1 FROM integrate_test.t1 JOIN integrate_test.t2 WHERE integrate_test.t1.a = 10;
ERROR 1105 (HY000): unsupported: currently.not.support.multitables.in.delete

DELETE /*test parse error*/ FROM integrate_test.t1 alias USING integrate_test.t1, integrate_test.t2 alias WHERE integrate_test.t1.a = alias.a;
ERROR 1149 (42000): You have an error in your SQL syntax; check the manual that corresponds to your MySQL server version for the right syntax to use, syntax error at position 43 near 'using'

DELETE /*test parse error*/ FROM integrate_test.t1 alias USING integrate_test.t1, integrate_test.t1 alias WHERE integrate_test.t1.a = alias.a;
ERROR 1149 (42000): You have an error in your SQL syntax; check the manual that corresponds to your MySQL server version for the right syntax to use, syntax error at position 43 near 'using'

DELETE /*test parse error*/ FROM integrate_test.t1 alias USING integrate_test.t1 alias WHERE a = 2;
ERROR 1149 (42000): You have an error in your SQL syntax; check the manual that corresponds to your MySQL server version for the right syntax to use, syntax error at position 43 near 'using'

drop table integrate_test.t1, integrate_test.t2;


CREATE /*test list*/ TABLE integrate_test.t1 ( a int PRIMARY KEY ) ENGINE=InnoDB DEFAULT CHARSET=utf8 partition by list(a) (partition backend1 values in (0,1,3), partition backend2 values in (2,5,8));

DELETE FROM integrate_test.t1 WHERE a > 0 ORDER BY a;

INSERT INTO integrate_test.t1 VALUES (0),(1),(2);

DELETE FROM integrate_test.t1 WHERE a > 0 ORDER BY a LIMIT 1;

SELECT * FROM integrate_test.t1;
a
0

DROP TABLE integrate_test.t1;


drop database integrate_test;
82 changes: 82 additions & 0 deletions intergration/radon-test/t/delete.test
Original file line number Diff line number Diff line change
@@ -0,0 +1,82 @@
create database if not exists integrate_test DEFAULT CHARSET=utf8;
drop table if exists integrate_test.t1, integrate_test.t2;

CREATE /*test hash*/ TABLE integrate_test.t1 (a tinyint(3) key, b tinyint(5));
INSERT INTO integrate_test.t1 VALUES (1,1);
INSERT LOW_PRIORITY INTO integrate_test.t1 VALUES (2,2);
INSERT INTO integrate_test.t1 VALUES (3,3);
DELETE from integrate_test.t1 where a=1 limit 1;
DELETE LOW_PRIORITY from integrate_test.t1 where a=2;
select * from integrate_test.t1;
INSERT INTO integrate_test.t1 VALUES (1,1);
DELETE quick from integrate_test.t1;
select * from integrate_test.t1;
drop table integrate_test.t1;

create table integrate_test.t2 (
a bigint not null,
b bigint not null default 0,
c bigint not null default 0,
d bigint not null default 0,
e bigint not null default 0,
f bigint not null default 0,
g bigint not null default 0,
h bigint not null default 0,
i bigint not null default 0,
j bigint not null default 0,
primary key (a,b,c,d,e,f,g,h,i,j));
insert into integrate_test.t2 (a) values (2),(4),(6),(8),(10),(12),(14),(16),(18),(20),(22),(24),(26),(23);
delete from integrate_test.t2 where a=26;
select * from integrate_test.t2 order by a;
drop table integrate_test.t2;
create table integrate_test.t1 (
a bigint not null,
b bigint not null default 0,
c bigint not null default 0,
d bigint not null default 0,
e bigint not null default 0,
f bigint not null default 0,
g bigint not null default 0,
h bigint not null default 0,
i bigint not null default 0,
j bigint not null default 0,
primary key (a,b,c,d,e,f,g,h,i,j));
insert into integrate_test.t1 (a) values (2),(4),(6),(8),(10),(12),(14),(16),(18),(20),(22),(24),(26),(23),(27);
delete from integrate_test.t1 where a=27;
select * from integrate_test.t1 order by a;
drop table integrate_test.t1;

CREATE /*test error, column not exist*/ TABLE integrate_test.t1 (
`i` int(10) NOT NULL default '0',
`i2` int(10) NOT NULL default '0',
PRIMARY KEY (`i`)
);
DELETE FROM integrate_test.t1 WHERE post='1';
drop table integrate_test.t1;

create /*test global*/ table integrate_test.t2 (a bigint not null auto_increment primary key, b char(32)) global;
insert into integrate_test.t2 (a,b) values (1,'apple'), (2,'apple');
select * from integrate_test.t2;
delete /*test unsupport, currently not support delete multitables*/ integrate_test.t2 from integrate_test.t2, integrate_test.t2 as t1 where integrate_test.t2.b = integrate_test.t1.b and integrate_test.t2.a > integrate_test.t1.a;
delete /*test unsupport, currently not support delete with partition*/ from integrate_test.t2 partition (p0) where a = 1;
DELETE /*test unsupport, currently not support delete with subquery*/ FROM integrate_test.t2 ORDER BY (SELECT x);
drop table integrate_test.t2;

CREATE TABLE integrate_test.t1(a INTEGER PRIMARY KEY) single;
INSERT INTO integrate_test.t1 VALUES(10),(20);
CREATE TABLE integrate_test.t2(b INTEGER key);
INSERT INTO integrate_test.t2 VALUES(10),(20);
DELETE /*test unsupport with join, not support delete with multitables*/ integrate_test.t1 FROM integrate_test.t1 JOIN integrate_test.t2 WHERE integrate_test.t1.a = 10;
DELETE /*test parse error*/ FROM integrate_test.t1 alias USING integrate_test.t1, integrate_test.t2 alias WHERE integrate_test.t1.a = alias.a;
DELETE /*test parse error*/ FROM integrate_test.t1 alias USING integrate_test.t1, integrate_test.t1 alias WHERE integrate_test.t1.a = alias.a;
DELETE /*test parse error*/ FROM integrate_test.t1 alias USING integrate_test.t1 alias WHERE a = 2;
drop table integrate_test.t1, integrate_test.t2;

CREATE /*test list*/ TABLE integrate_test.t1 ( a int PRIMARY KEY ) ENGINE=InnoDB DEFAULT CHARSET=utf8 partition by list(a) (partition backend1 values in (0,1,3), partition backend2 values in (2,5,8));
DELETE FROM integrate_test.t1 WHERE a > 0 ORDER BY a;
INSERT INTO integrate_test.t1 VALUES (0),(1),(2);
DELETE FROM integrate_test.t1 WHERE a > 0 ORDER BY a LIMIT 1;
SELECT * FROM integrate_test.t1;
DROP TABLE integrate_test.t1;

drop database integrate_test;
4 changes: 2 additions & 2 deletions src/planner/builder/expr.go
Original file line number Diff line number Diff line change
Expand Up @@ -122,8 +122,8 @@ func parseWhereOrJoinExprs(exprs sqlparser.Expr, tbInfos map[string]*tableInfo)
return joins, wheres, nil
}

// GetDMLRouting used to get the routing from the where clause.
func GetDMLRouting(database, table, shardkey string, where *sqlparser.Where, router *router.Router) ([]router.Segment, error) {
// LookupFromWhere used to get the routing from the where clause.
func LookupFromWhere(database, table, shardkey string, where *sqlparser.Where, router *router.Router) ([]router.Segment, error) {
if shardkey != "" && where != nil {
filters := splitAndExpression(nil, where.Expr)
for _, filter := range filters {
Expand Down
8 changes: 4 additions & 4 deletions src/planner/builder/expr_test.go
Original file line number Diff line number Diff line change
Expand Up @@ -18,7 +18,7 @@ import (
"github.com/xelabs/go-mysqlstack/xlog"
)

func TestGetDMLRouting(t *testing.T) {
func TestLookupFromWhere(t *testing.T) {
querys := []string{
"select * from B where B.b between 10 and 20 and B.id = 10",
"select * from B where id = 10",
Expand Down Expand Up @@ -53,13 +53,13 @@ func TestGetDMLRouting(t *testing.T) {
node, err := sqlparser.Parse(query)
n := node.(*sqlparser.Select)
assert.Nil(t, err)
got, err := GetDMLRouting(database, "B", "id", n.Where, route)
got, err := LookupFromWhere(database, "B", "id", n.Where, route)
assert.Nil(t, err)
assert.Equal(t, want[i], len(got))
}
}

func TestGetDMLRoutingErr(t *testing.T) {
func TestLookupFromWhereErr(t *testing.T) {
testcases := []struct {
query string
out string
Expand All @@ -84,7 +84,7 @@ func TestGetDMLRoutingErr(t *testing.T) {
node, err := sqlparser.Parse(testcase.query)
n := node.(*sqlparser.Select)
assert.Nil(t, err)
_, err = GetDMLRouting(database, "B", "id", n.Where, route)
_, err = LookupFromWhere(database, "B", "id", n.Where, route)
assert.NotNil(t, err)
assert.Equal(t, testcase.out, err.Error())
}
Expand Down
Loading

0 comments on commit 27a46b3

Please sign in to comment.