├── .travis.yml ├── LICENSE ├── README.md ├── README.template ├── go.mod ├── go.sum ├── query └── query.go ├── sql.go └── sql_test.go /.travis.yml: -------------------------------------------------------------------------------- 1 | language: go 2 | 3 | go: 4 | - 1.11 5 | 6 | install: 7 | - go get golang.org/x/tools/cmd/cover 8 | - go get github.com/mattn/goveralls 9 | 10 | env: 11 | secure: "Bqfz/WUq/TJbAJTQYNE6+TLQoeRlksRIrkJ0OJlYhzK9p9n9Fn4JKLSiFVuJr+pM+ucGlSNouqY9q8KqgHW9PuFjN01YBZvXLj1Bpfq4+hgIxNCUHVZ2cgHwpfqHrgXA+tI6DiggBgZdh/uQb892vuYLBq4qp91nZAsdbZbZcNpEUsR+2UjpXUFmcQM2yfmEHYZ2c8cuCw9Riz05o9ZAl6FLQSPGm9A0elCOkPqpeK2y87xYDNowv11EO7QWFDas+mAEwyirudmPUgPLo0gYovVdDUg+9UVOxFnS0VBz1mdS7lhKFJ0WXrMEWX8sOymWbgmod71DTgXG9y8iW+zt+jcJZbMDA3JxmuA9IqOBFRAnzt23UtMZI6QgybhB+mZuJ54TlUlYGBw1RxfHN94leNTrXjw5HFARca/UGW07FYFDQXqqyjv2Hv0S079NDF0lv3JQ+ujjQR3clN06eEtegzcU5YSW+G73nrGXk/WsZqNQgSmRE95x0XW3pxL5Kr4FFDaeDexnGjPGjOllrJDTvTNs0y663nhF7yrPnDSDxkk0mEKLanCA+VKN8NGwsDx9V4HWH8sZ5UF+h6FvB0C5yh6J6YHPrYtjgZCd7KjRagGGo44K2Xfj1RfgznPYYzaEiQadVyUmvAMctAU0BmJYjgOqYABh6YXBKME/KLfhMjU=" 12 | 13 | script: 14 | - GO111MODULE=on go mod vendor 15 | - go test -v -covermode=count -coverprofile=coverage.out ./... 16 | - 'if [ "$TRAVIS_PULL_REQUEST" = "false" ]; then $HOME/gopath/bin/goveralls -coverprofile=coverage.out -service=travis-ci -repotoken $COVERALLS_TOKEN; fi' 17 | -------------------------------------------------------------------------------- /LICENSE: -------------------------------------------------------------------------------- 1 | MIT License 2 | 3 | Copyright (c) 2019 Mariano Gappa 4 | 5 | Permission is hereby granted, free of charge, to any person obtaining a copy 6 | of this software and associated documentation files (the "Software"), to deal 7 | in the Software without restriction, including without limitation the rights 8 | to use, copy, modify, merge, publish, distribute, sublicense, and/or sell 9 | copies of the Software, and to permit persons to whom the Software is 10 | furnished to do so, subject to the following conditions: 11 | 12 | The above copyright notice and this permission notice shall be included in all 13 | copies or substantial portions of the Software. 14 | 15 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR 16 | IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, 17 | FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE 18 | AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER 19 | LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, 20 | OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE 21 | SOFTWARE. 22 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # sqlparser - meant for querying csv files 2 | [![Build Status](https://img.shields.io/travis/marianogappa/sqlparser.svg)](https://travis-ci.org/marianogappa/sqlparser) [![Coverage Status](https://coveralls.io/repos/github/marianogappa/sqlparser/badge.svg?branch=master)](https://coveralls.io/github/MarianoGappa/sqlparser?branch=master) [![GitHub license](https://img.shields.io/badge/license-MIT-blue.svg)](https://raw.githubusercontent.com/marianogappa/sqlparser/master/LICENSE) [![Go Report Card](https://goreportcard.com/badge/github.com/marianogappa/sqlparser?style=flat-square)](https://goreportcard.com/report/github.com/marianogappa/sqlparser) [![GoDoc](https://godoc.org/github.com/marianogappa/sqlparser?status.svg)](https://godoc.org/github.com/marianogappa/sqlparser) 3 | ### Usage 4 | 5 | ``` 6 | package main 7 | 8 | import ( 9 | "fmt" 10 | "log" 11 | 12 | "github.com/marianogappa/sqlparser" 13 | ) 14 | 15 | func main() { 16 | query, err := sqlparser.Parse("SELECT a, b, c FROM 'd' WHERE e = '1' AND f > '2'") 17 | if err != nil { 18 | log.Fatal(err) 19 | } 20 | fmt.Printf("%+#v", query) 21 | } 22 | ``` 23 | 24 | 25 | ### Example: SELECT works 26 | 27 | ``` 28 | query, err := sqlparser.Parse(`SELECT a FROM 'b'`) 29 | 30 | query.Query { 31 | Type: Select 32 | TableName: b 33 | Conditions: [] 34 | Updates: map[] 35 | Inserts: [] 36 | Fields: [a] 37 | Aliases: map[] 38 | } 39 | ``` 40 | 41 | ### Example: SELECT works with lowercase 42 | 43 | ``` 44 | query, err := sqlparser.Parse(`select a fRoM 'b'`) 45 | 46 | query.Query { 47 | Type: Select 48 | TableName: b 49 | Conditions: [] 50 | Updates: map[] 51 | Inserts: [] 52 | Fields: [a] 53 | Aliases: map[] 54 | } 55 | ``` 56 | 57 | ### Example: SELECT many fields works 58 | 59 | ``` 60 | query, err := sqlparser.Parse(`SELECT a, c, d FROM 'b'`) 61 | 62 | query.Query { 63 | Type: Select 64 | TableName: b 65 | Conditions: [] 66 | Updates: map[] 67 | Inserts: [] 68 | Fields: [a c d] 69 | Aliases: map[] 70 | } 71 | ``` 72 | 73 | ### Example: SELECT with alias works 74 | 75 | ``` 76 | query, err := sqlparser.Parse(`SELECT a as z, b as y, c FROM 'b'`) 77 | 78 | query.Query { 79 | Type: Select 80 | TableName: b 81 | Conditions: [] 82 | Updates: map[] 83 | Inserts: [] 84 | Fields: [a b c] 85 | Aliases: map[a:z b:y] 86 | } 87 | ``` 88 | 89 | ### Example: SELECT with WHERE with = works 90 | 91 | ``` 92 | query, err := sqlparser.Parse(`SELECT a, c, d FROM 'b' WHERE a = ''`) 93 | 94 | query.Query { 95 | Type: Select 96 | TableName: b 97 | Conditions: [ 98 | { 99 | Operand1: a, 100 | Operand1IsField: true, 101 | Operator: Eq, 102 | Operand2: , 103 | Operand2IsField: false, 104 | }] 105 | Updates: map[] 106 | Inserts: [] 107 | Fields: [a c d] 108 | Aliases: map[] 109 | } 110 | ``` 111 | 112 | ### Example: SELECT with WHERE with < works 113 | 114 | ``` 115 | query, err := sqlparser.Parse(`SELECT a, c, d FROM 'b' WHERE a < '1'`) 116 | 117 | query.Query { 118 | Type: Select 119 | TableName: b 120 | Conditions: [ 121 | { 122 | Operand1: a, 123 | Operand1IsField: true, 124 | Operator: Lt, 125 | Operand2: 1, 126 | Operand2IsField: false, 127 | }] 128 | Updates: map[] 129 | Inserts: [] 130 | Fields: [a c d] 131 | Aliases: map[] 132 | } 133 | ``` 134 | 135 | ### Example: SELECT with WHERE with <= works 136 | 137 | ``` 138 | query, err := sqlparser.Parse(`SELECT a, c, d FROM 'b' WHERE a <= '1'`) 139 | 140 | query.Query { 141 | Type: Select 142 | TableName: b 143 | Conditions: [ 144 | { 145 | Operand1: a, 146 | Operand1IsField: true, 147 | Operator: Lte, 148 | Operand2: 1, 149 | Operand2IsField: false, 150 | }] 151 | Updates: map[] 152 | Inserts: [] 153 | Fields: [a c d] 154 | Aliases: map[] 155 | } 156 | ``` 157 | 158 | ### Example: SELECT with WHERE with > works 159 | 160 | ``` 161 | query, err := sqlparser.Parse(`SELECT a, c, d FROM 'b' WHERE a > '1'`) 162 | 163 | query.Query { 164 | Type: Select 165 | TableName: b 166 | Conditions: [ 167 | { 168 | Operand1: a, 169 | Operand1IsField: true, 170 | Operator: Gt, 171 | Operand2: 1, 172 | Operand2IsField: false, 173 | }] 174 | Updates: map[] 175 | Inserts: [] 176 | Fields: [a c d] 177 | Aliases: map[] 178 | } 179 | ``` 180 | 181 | ### Example: SELECT with WHERE with >= works 182 | 183 | ``` 184 | query, err := sqlparser.Parse(`SELECT a, c, d FROM 'b' WHERE a >= '1'`) 185 | 186 | query.Query { 187 | Type: Select 188 | TableName: b 189 | Conditions: [ 190 | { 191 | Operand1: a, 192 | Operand1IsField: true, 193 | Operator: Gte, 194 | Operand2: 1, 195 | Operand2IsField: false, 196 | }] 197 | Updates: map[] 198 | Inserts: [] 199 | Fields: [a c d] 200 | Aliases: map[] 201 | } 202 | ``` 203 | 204 | ### Example: SELECT with WHERE with != works 205 | 206 | ``` 207 | query, err := sqlparser.Parse(`SELECT a, c, d FROM 'b' WHERE a != '1'`) 208 | 209 | query.Query { 210 | Type: Select 211 | TableName: b 212 | Conditions: [ 213 | { 214 | Operand1: a, 215 | Operand1IsField: true, 216 | Operator: Ne, 217 | Operand2: 1, 218 | Operand2IsField: false, 219 | }] 220 | Updates: map[] 221 | Inserts: [] 222 | Fields: [a c d] 223 | Aliases: map[] 224 | } 225 | ``` 226 | 227 | ### Example: SELECT with WHERE with != works (comparing field against another field) 228 | 229 | ``` 230 | query, err := sqlparser.Parse(`SELECT a, c, d FROM 'b' WHERE a != b`) 231 | 232 | query.Query { 233 | Type: Select 234 | TableName: b 235 | Conditions: [ 236 | { 237 | Operand1: a, 238 | Operand1IsField: true, 239 | Operator: Ne, 240 | Operand2: b, 241 | Operand2IsField: true, 242 | }] 243 | Updates: map[] 244 | Inserts: [] 245 | Fields: [a c d] 246 | Aliases: map[] 247 | } 248 | ``` 249 | 250 | ### Example: SELECT * works 251 | 252 | ``` 253 | query, err := sqlparser.Parse(`SELECT * FROM 'b'`) 254 | 255 | query.Query { 256 | Type: Select 257 | TableName: b 258 | Conditions: [] 259 | Updates: map[] 260 | Inserts: [] 261 | Fields: [*] 262 | Aliases: map[] 263 | } 264 | ``` 265 | 266 | ### Example: SELECT a, * works 267 | 268 | ``` 269 | query, err := sqlparser.Parse(`SELECT a, * FROM 'b'`) 270 | 271 | query.Query { 272 | Type: Select 273 | TableName: b 274 | Conditions: [] 275 | Updates: map[] 276 | Inserts: [] 277 | Fields: [a *] 278 | Aliases: map[] 279 | } 280 | ``` 281 | 282 | ### Example: SELECT with WHERE with two conditions using AND works 283 | 284 | ``` 285 | query, err := sqlparser.Parse(`SELECT a, c, d FROM 'b' WHERE a != '1' AND b = '2'`) 286 | 287 | query.Query { 288 | Type: Select 289 | TableName: b 290 | Conditions: [ 291 | { 292 | Operand1: a, 293 | Operand1IsField: true, 294 | Operator: Ne, 295 | Operand2: 1, 296 | Operand2IsField: false, 297 | } 298 | { 299 | Operand1: b, 300 | Operand1IsField: true, 301 | Operator: Eq, 302 | Operand2: 2, 303 | Operand2IsField: false, 304 | }] 305 | Updates: map[] 306 | Inserts: [] 307 | Fields: [a c d] 308 | Aliases: map[] 309 | } 310 | ``` 311 | 312 | ### Example: UPDATE works 313 | 314 | ``` 315 | query, err := sqlparser.Parse(`UPDATE 'a' SET b = 'hello' WHERE a = '1'`) 316 | 317 | query.Query { 318 | Type: Update 319 | TableName: a 320 | Conditions: [ 321 | { 322 | Operand1: a, 323 | Operand1IsField: true, 324 | Operator: Eq, 325 | Operand2: 1, 326 | Operand2IsField: false, 327 | }] 328 | Updates: map[b:hello] 329 | Inserts: [] 330 | Fields: [] 331 | Aliases: map[] 332 | } 333 | ``` 334 | 335 | ### Example: UPDATE works with simple quote inside 336 | 337 | ``` 338 | query, err := sqlparser.Parse(`UPDATE 'a' SET b = 'hello\'world' WHERE a = '1'`) 339 | 340 | query.Query { 341 | Type: Update 342 | TableName: a 343 | Conditions: [ 344 | { 345 | Operand1: a, 346 | Operand1IsField: true, 347 | Operator: Eq, 348 | Operand2: 1, 349 | Operand2IsField: false, 350 | }] 351 | Updates: map[b:hello\'world] 352 | Inserts: [] 353 | Fields: [] 354 | Aliases: map[] 355 | } 356 | ``` 357 | 358 | ### Example: UPDATE with multiple SETs works 359 | 360 | ``` 361 | query, err := sqlparser.Parse(`UPDATE 'a' SET b = 'hello', c = 'bye' WHERE a = '1'`) 362 | 363 | query.Query { 364 | Type: Update 365 | TableName: a 366 | Conditions: [ 367 | { 368 | Operand1: a, 369 | Operand1IsField: true, 370 | Operator: Eq, 371 | Operand2: 1, 372 | Operand2IsField: false, 373 | }] 374 | Updates: map[b:hello c:bye] 375 | Inserts: [] 376 | Fields: [] 377 | Aliases: map[] 378 | } 379 | ``` 380 | 381 | ### Example: UPDATE with multiple SETs and multiple conditions works 382 | 383 | ``` 384 | query, err := sqlparser.Parse(`UPDATE 'a' SET b = 'hello', c = 'bye' WHERE a = '1' AND b = '789'`) 385 | 386 | query.Query { 387 | Type: Update 388 | TableName: a 389 | Conditions: [ 390 | { 391 | Operand1: a, 392 | Operand1IsField: true, 393 | Operator: Eq, 394 | Operand2: 1, 395 | Operand2IsField: false, 396 | } 397 | { 398 | Operand1: b, 399 | Operand1IsField: true, 400 | Operator: Eq, 401 | Operand2: 789, 402 | Operand2IsField: false, 403 | }] 404 | Updates: map[b:hello c:bye] 405 | Inserts: [] 406 | Fields: [] 407 | Aliases: map[] 408 | } 409 | ``` 410 | 411 | ### Example: DELETE with WHERE works 412 | 413 | ``` 414 | query, err := sqlparser.Parse(`DELETE FROM 'a' WHERE b = '1'`) 415 | 416 | query.Query { 417 | Type: Delete 418 | TableName: a 419 | Conditions: [ 420 | { 421 | Operand1: b, 422 | Operand1IsField: true, 423 | Operator: Eq, 424 | Operand2: 1, 425 | Operand2IsField: false, 426 | }] 427 | Updates: map[] 428 | Inserts: [] 429 | Fields: [] 430 | Aliases: map[] 431 | } 432 | ``` 433 | 434 | ### Example: INSERT works 435 | 436 | ``` 437 | query, err := sqlparser.Parse(`INSERT INTO 'a' (b) VALUES ('1')`) 438 | 439 | query.Query { 440 | Type: Insert 441 | TableName: a 442 | Conditions: [] 443 | Updates: map[] 444 | Inserts: [[1]] 445 | Fields: [b] 446 | Aliases: map[] 447 | } 448 | ``` 449 | 450 | ### Example: INSERT with multiple fields works 451 | 452 | ``` 453 | query, err := sqlparser.Parse(`INSERT INTO 'a' (b,c, d) VALUES ('1','2' , '3' )`) 454 | 455 | query.Query { 456 | Type: Insert 457 | TableName: a 458 | Conditions: [] 459 | Updates: map[] 460 | Inserts: [[1 2 3]] 461 | Fields: [b c d] 462 | Aliases: map[] 463 | } 464 | ``` 465 | 466 | ### Example: INSERT with multiple fields and multiple values works 467 | 468 | ``` 469 | query, err := sqlparser.Parse(`INSERT INTO 'a' (b,c, d) VALUES ('1','2' , '3' ),('4','5' ,'6' )`) 470 | 471 | query.Query { 472 | Type: Insert 473 | TableName: a 474 | Conditions: [] 475 | Updates: map[] 476 | Inserts: [[1 2 3] [4 5 6]] 477 | Fields: [b c d] 478 | Aliases: map[] 479 | } 480 | ``` 481 | 482 | 483 | 484 | ### Example: empty query fails 485 | 486 | ``` 487 | query, err := sqlparser.Parse(``) 488 | 489 | query type cannot be empty 490 | ``` 491 | 492 | ### Example: SELECT without FROM fails 493 | 494 | ``` 495 | query, err := sqlparser.Parse(`SELECT`) 496 | 497 | table name cannot be empty 498 | ``` 499 | 500 | ### Example: SELECT without fields fails 501 | 502 | ``` 503 | query, err := sqlparser.Parse(`SELECT FROM 'a'`) 504 | 505 | at SELECT: expected field to SELECT 506 | ``` 507 | 508 | ### Example: SELECT with comma and empty field fails 509 | 510 | ``` 511 | query, err := sqlparser.Parse(`SELECT b, FROM 'a'`) 512 | 513 | at SELECT: expected field to SELECT 514 | ``` 515 | 516 | ### Example: SELECT with empty WHERE fails 517 | 518 | ``` 519 | query, err := sqlparser.Parse(`SELECT a, c, d FROM 'b' WHERE`) 520 | 521 | at WHERE: empty WHERE clause 522 | ``` 523 | 524 | ### Example: SELECT with WHERE with only operand fails 525 | 526 | ``` 527 | query, err := sqlparser.Parse(`SELECT a, c, d FROM 'b' WHERE a`) 528 | 529 | at WHERE: condition without operator 530 | ``` 531 | 532 | ### Example: Empty UPDATE fails 533 | 534 | ``` 535 | query, err := sqlparser.Parse(`UPDATE`) 536 | 537 | table name cannot be empty 538 | ``` 539 | 540 | ### Example: Incomplete UPDATE with table name fails 541 | 542 | ``` 543 | query, err := sqlparser.Parse(`UPDATE 'a'`) 544 | 545 | at WHERE: WHERE clause is mandatory for UPDATE & DELETE 546 | ``` 547 | 548 | ### Example: Incomplete UPDATE with table name and SET fails 549 | 550 | ``` 551 | query, err := sqlparser.Parse(`UPDATE 'a' SET`) 552 | 553 | at WHERE: WHERE clause is mandatory for UPDATE & DELETE 554 | ``` 555 | 556 | ### Example: Incomplete UPDATE with table name, SET with a field but no value and WHERE fails 557 | 558 | ``` 559 | query, err := sqlparser.Parse(`UPDATE 'a' SET b WHERE`) 560 | 561 | at UPDATE: expected '=' 562 | ``` 563 | 564 | ### Example: Incomplete UPDATE with table name, SET with a field and = but no value and WHERE fails 565 | 566 | ``` 567 | query, err := sqlparser.Parse(`UPDATE 'a' SET b = WHERE`) 568 | 569 | at UPDATE: expected quoted value 570 | ``` 571 | 572 | ### Example: Incomplete UPDATE due to no WHERE clause fails 573 | 574 | ``` 575 | query, err := sqlparser.Parse(`UPDATE 'a' SET b = 'hello' WHERE`) 576 | 577 | at WHERE: empty WHERE clause 578 | ``` 579 | 580 | ### Example: Incomplete UPDATE due incomplete WHERE clause fails 581 | 582 | ``` 583 | query, err := sqlparser.Parse(`UPDATE 'a' SET b = 'hello' WHERE a`) 584 | 585 | at WHERE: condition without operator 586 | ``` 587 | 588 | ### Example: Empty DELETE fails 589 | 590 | ``` 591 | query, err := sqlparser.Parse(`DELETE FROM`) 592 | 593 | table name cannot be empty 594 | ``` 595 | 596 | ### Example: DELETE without WHERE fails 597 | 598 | ``` 599 | query, err := sqlparser.Parse(`DELETE FROM 'a'`) 600 | 601 | at WHERE: WHERE clause is mandatory for UPDATE & DELETE 602 | ``` 603 | 604 | ### Example: DELETE with empty WHERE fails 605 | 606 | ``` 607 | query, err := sqlparser.Parse(`DELETE FROM 'a' WHERE`) 608 | 609 | at WHERE: empty WHERE clause 610 | ``` 611 | 612 | ### Example: DELETE with WHERE with field but no operator fails 613 | 614 | ``` 615 | query, err := sqlparser.Parse(`DELETE FROM 'a' WHERE b`) 616 | 617 | at WHERE: condition without operator 618 | ``` 619 | 620 | ### Example: Empty INSERT fails 621 | 622 | ``` 623 | query, err := sqlparser.Parse(`INSERT INTO`) 624 | 625 | table name cannot be empty 626 | ``` 627 | 628 | ### Example: INSERT with no rows to insert fails 629 | 630 | ``` 631 | query, err := sqlparser.Parse(`INSERT INTO 'a'`) 632 | 633 | at INSERT INTO: need at least one row to insert 634 | ``` 635 | 636 | ### Example: INSERT with incomplete value section fails 637 | 638 | ``` 639 | query, err := sqlparser.Parse(`INSERT INTO 'a' (`) 640 | 641 | at INSERT INTO: need at least one row to insert 642 | ``` 643 | 644 | ### Example: INSERT with incomplete value section fails #2 645 | 646 | ``` 647 | query, err := sqlparser.Parse(`INSERT INTO 'a' (b`) 648 | 649 | at INSERT INTO: need at least one row to insert 650 | ``` 651 | 652 | ### Example: INSERT with incomplete value section fails #3 653 | 654 | ``` 655 | query, err := sqlparser.Parse(`INSERT INTO 'a' (b)`) 656 | 657 | at INSERT INTO: need at least one row to insert 658 | ``` 659 | 660 | ### Example: INSERT with incomplete value section fails #4 661 | 662 | ``` 663 | query, err := sqlparser.Parse(`INSERT INTO 'a' (b) VALUES`) 664 | 665 | at INSERT INTO: need at least one row to insert 666 | ``` 667 | 668 | ### Example: INSERT with incomplete row fails 669 | 670 | ``` 671 | query, err := sqlparser.Parse(`INSERT INTO 'a' (b) VALUES (`) 672 | 673 | at INSERT INTO: value count doesn't match field count 674 | ``` 675 | 676 | ### Example: INSERT * fails 677 | 678 | ``` 679 | query, err := sqlparser.Parse(`INSERT INTO 'a' (*) VALUES ('1')`) 680 | 681 | at INSERT INTO: expected at least one field to insert 682 | ``` 683 | 684 | -------------------------------------------------------------------------------- /README.template: -------------------------------------------------------------------------------- 1 | {{- $types := .Types -}} 2 | {{- $operators := .Operators -}} 3 | # sqlparser - meant for querying csv files 4 | [![Build Status](https://img.shields.io/travis/marianogappa/sqlparser.svg)](https://travis-ci.org/marianogappa/sqlparser) [![Coverage Status](https://coveralls.io/repos/github/marianogappa/sqlparser/badge.svg?branch=master)](https://coveralls.io/github/MarianoGappa/sqlparser?branch=master) [![GitHub license](https://img.shields.io/badge/license-MIT-blue.svg)](https://raw.githubusercontent.com/marianogappa/sqlparser/master/LICENSE) [![Go Report Card](https://goreportcard.com/badge/github.com/marianogappa/sqlparser?style=flat-square)](https://goreportcard.com/report/github.com/marianogappa/sqlparser) [![GoDoc](https://godoc.org/github.com/marianogappa/sqlparser?status.svg)](https://godoc.org/github.com/marianogappa/sqlparser) 5 | ### Usage 6 | 7 | ``` 8 | package main 9 | 10 | import ( 11 | "fmt" 12 | "log" 13 | 14 | "github.com/marianogappa/sqlparser" 15 | ) 16 | 17 | func main() { 18 | query, err := sqlparser.Parse("SELECT a, b, c FROM 'd' WHERE e = '1' AND f > '2'") 19 | if err != nil { 20 | log.Fatal(err) 21 | } 22 | fmt.Printf("%+#v", query) 23 | } 24 | ``` 25 | 26 | {{range .NoErrorExamples}} 27 | ### Example: {{.Name}} 28 | 29 | ``` 30 | query, err := sqlparser.Parse(`{{.SQL}}`) 31 | 32 | query.Query { 33 | Type: {{index $types .Expected.Type}} 34 | TableName: {{.Expected.TableName}} 35 | Conditions: [{{range .Expected.Conditions}} 36 | { 37 | Operand1: {{.Operand1}}, 38 | Operand1IsField: {{.Operand1IsField}}, 39 | Operator: {{index $operators .Operator}}, 40 | Operand2: {{.Operand2}}, 41 | Operand2IsField: {{.Operand2IsField}}, 42 | }{{end -}}] 43 | Updates: {{.Expected.Updates}} 44 | Inserts: {{.Expected.Inserts}} 45 | Fields: {{.Expected.Fields}} 46 | Aliases: {{.Expected.Aliases}} 47 | } 48 | ``` 49 | {{end}} 50 | 51 | {{range .ErrorExamples}} 52 | ### Example: {{.Name}} 53 | 54 | ``` 55 | query, err := sqlparser.Parse(`{{.SQL}}`) 56 | 57 | {{.Err}} 58 | ``` 59 | {{end}} 60 | -------------------------------------------------------------------------------- /go.mod: -------------------------------------------------------------------------------- 1 | module github.com/marianogappa/sqlparser 2 | 3 | go 1.14 4 | 5 | require github.com/stretchr/testify v1.3.0 6 | -------------------------------------------------------------------------------- /go.sum: -------------------------------------------------------------------------------- 1 | github.com/davecgh/go-spew v1.1.0 h1:ZDRjVQ15GmhC3fiQ8ni8+OwkZQO4DARzQgrnXU1Liz8= 2 | github.com/davecgh/go-spew v1.1.0/go.mod h1:J7Y8YcW2NihsgmVo/mv3lAwl/skON4iLHjSsI+c5H38= 3 | github.com/pmezard/go-difflib v1.0.0 h1:4DBwDE0NGyQoBHbLQYPwSUPoCMWR5BEzIk/f1lZbAQM= 4 | github.com/pmezard/go-difflib v1.0.0/go.mod h1:iKH77koFhYxTK1pcRnkKkqfTogsbg7gZNVY4sRDYZ/4= 5 | github.com/stretchr/objx v0.1.0/go.mod h1:HFkY916IF+rwdDfMAkV7OtwuqBVzrE8GR6GFx+wExME= 6 | github.com/stretchr/testify v1.3.0 h1:TivCn/peBQ7UY8ooIcPgZFpTNSz0Q2U6UrFlUfqbe0Q= 7 | github.com/stretchr/testify v1.3.0/go.mod h1:M5WIy9Dh21IEIfnGCwXGc5bZfKNJtfHm1UVUgZn+9EI= 8 | -------------------------------------------------------------------------------- /query/query.go: -------------------------------------------------------------------------------- 1 | package query 2 | 3 | // Query represents a parsed query 4 | type Query struct { 5 | Type Type 6 | TableName string 7 | Conditions []Condition 8 | Updates map[string]string 9 | Inserts [][]string 10 | Fields []string // Used for SELECT (i.e. SELECTed field names) and INSERT (INSERTEDed field names) 11 | Aliases map[string]string 12 | } 13 | 14 | // Type is the type of SQL query, e.g. SELECT/UPDATE 15 | type Type int 16 | 17 | const ( 18 | // UnknownType is the zero value for a Type 19 | UnknownType Type = iota 20 | // Select represents a SELECT query 21 | Select 22 | // Update represents an UPDATE query 23 | Update 24 | // Insert represents an INSERT query 25 | Insert 26 | // Delete represents a DELETE query 27 | Delete 28 | ) 29 | 30 | // TypeString is a string slice with the names of all types in order 31 | var TypeString = []string{ 32 | "UnknownType", 33 | "Select", 34 | "Update", 35 | "Insert", 36 | "Delete", 37 | } 38 | 39 | // Operator is between operands in a condition 40 | type Operator int 41 | 42 | const ( 43 | // UnknownOperator is the zero value for an Operator 44 | UnknownOperator Operator = iota 45 | // Eq -> "=" 46 | Eq 47 | // Ne -> "!=" 48 | Ne 49 | // Gt -> ">" 50 | Gt 51 | // Lt -> "<" 52 | Lt 53 | // Gte -> ">=" 54 | Gte 55 | // Lte -> "<=" 56 | Lte 57 | ) 58 | 59 | // OperatorString is a string slice with the names of all operators in order 60 | var OperatorString = []string{ 61 | "UnknownOperator", 62 | "Eq", 63 | "Ne", 64 | "Gt", 65 | "Lt", 66 | "Gte", 67 | "Lte", 68 | } 69 | 70 | // Condition is a single boolean condition in a WHERE clause 71 | type Condition struct { 72 | // Operand1 is the left hand side operand 73 | Operand1 string 74 | // Operand1IsField determines if Operand1 is a literal or a field name 75 | Operand1IsField bool 76 | // Operator is e.g. "=", ">" 77 | Operator Operator 78 | // Operand1 is the right hand side operand 79 | Operand2 string 80 | // Operand2IsField determines if Operand2 is a literal or a field name 81 | Operand2IsField bool 82 | } 83 | -------------------------------------------------------------------------------- /sql.go: -------------------------------------------------------------------------------- 1 | package sqlparser 2 | 3 | import ( 4 | "fmt" 5 | "regexp" 6 | "strings" 7 | 8 | "github.com/marianogappa/sqlparser/query" 9 | ) 10 | 11 | // Parse takes a string representing a SQL query and parses it into a query.Query struct. It may fail. 12 | func Parse(sqls string) (query.Query, error) { 13 | qs, err := ParseMany([]string{sqls}) 14 | if len(qs) == 0 { 15 | return query.Query{}, err 16 | } 17 | return qs[0], err 18 | } 19 | 20 | // ParseMany takes a string slice representing many SQL queries and parses them into a query.Query struct slice. 21 | // It may fail. If it fails, it will stop at the first failure. 22 | func ParseMany(sqls []string) ([]query.Query, error) { 23 | qs := []query.Query{} 24 | for _, sql := range sqls { 25 | q, err := parse(sql) 26 | if err != nil { 27 | return qs, err 28 | } 29 | qs = append(qs, q) 30 | } 31 | return qs, nil 32 | } 33 | 34 | func parse(sql string) (query.Query, error) { 35 | return (&parser{0, strings.TrimSpace(sql), stepType, query.Query{}, nil, ""}).parse() 36 | } 37 | 38 | type step int 39 | 40 | const ( 41 | stepType step = iota 42 | stepSelectField 43 | stepSelectFrom 44 | stepSelectComma 45 | stepSelectFromTable 46 | stepInsertTable 47 | stepInsertFieldsOpeningParens 48 | stepInsertFields 49 | stepInsertFieldsCommaOrClosingParens 50 | stepInsertValuesOpeningParens 51 | stepInsertValuesRWord 52 | stepInsertValues 53 | stepInsertValuesCommaOrClosingParens 54 | stepInsertValuesCommaBeforeOpeningParens 55 | stepUpdateTable 56 | stepUpdateSet 57 | stepUpdateField 58 | stepUpdateEquals 59 | stepUpdateValue 60 | stepUpdateComma 61 | stepDeleteFromTable 62 | stepWhere 63 | stepWhereField 64 | stepWhereOperator 65 | stepWhereValue 66 | stepWhereAnd 67 | ) 68 | 69 | type parser struct { 70 | i int 71 | sql string 72 | step step 73 | query query.Query 74 | err error 75 | nextUpdateField string 76 | } 77 | 78 | func (p *parser) parse() (query.Query, error) { 79 | q, err := p.doParse() 80 | p.err = err 81 | if p.err == nil { 82 | p.err = p.validate() 83 | } 84 | p.logError() 85 | return q, p.err 86 | } 87 | 88 | func (p *parser) doParse() (query.Query, error) { 89 | for { 90 | if p.i >= len(p.sql) { 91 | return p.query, p.err 92 | } 93 | switch p.step { 94 | case stepType: 95 | switch strings.ToUpper(p.peek()) { 96 | case "SELECT": 97 | p.query.Type = query.Select 98 | p.pop() 99 | p.step = stepSelectField 100 | case "INSERT INTO": 101 | p.query.Type = query.Insert 102 | p.pop() 103 | p.step = stepInsertTable 104 | case "UPDATE": 105 | p.query.Type = query.Update 106 | p.query.Updates = map[string]string{} 107 | p.pop() 108 | p.step = stepUpdateTable 109 | case "DELETE FROM": 110 | p.query.Type = query.Delete 111 | p.pop() 112 | p.step = stepDeleteFromTable 113 | default: 114 | return p.query, fmt.Errorf("invalid query type") 115 | } 116 | case stepSelectField: 117 | identifier := p.peek() 118 | if !isIdentifierOrAsterisk(identifier) { 119 | return p.query, fmt.Errorf("at SELECT: expected field to SELECT") 120 | } 121 | p.query.Fields = append(p.query.Fields, identifier) 122 | p.pop() 123 | maybeFrom := p.peek() 124 | if strings.ToUpper(maybeFrom) == "AS" { 125 | p.pop() 126 | alias := p.peek() 127 | if !isIdentifier(alias) { 128 | return p.query, fmt.Errorf("at SELECT: expected field alias for \"" + identifier + " as\" to SELECT") 129 | } 130 | if p.query.Aliases == nil { 131 | p.query.Aliases = make(map[string]string) 132 | } 133 | p.query.Aliases[identifier] = alias 134 | p.pop() 135 | maybeFrom = p.peek() 136 | } 137 | if strings.ToUpper(maybeFrom) == "FROM" { 138 | p.step = stepSelectFrom 139 | continue 140 | } 141 | p.step = stepSelectComma 142 | case stepSelectComma: 143 | commaRWord := p.peek() 144 | if commaRWord != "," { 145 | return p.query, fmt.Errorf("at SELECT: expected comma or FROM") 146 | } 147 | p.pop() 148 | p.step = stepSelectField 149 | case stepSelectFrom: 150 | fromRWord := p.peek() 151 | if strings.ToUpper(fromRWord) != "FROM" { 152 | return p.query, fmt.Errorf("at SELECT: expected FROM") 153 | } 154 | p.pop() 155 | p.step = stepSelectFromTable 156 | case stepSelectFromTable: 157 | tableName := p.peek() 158 | if len(tableName) == 0 { 159 | return p.query, fmt.Errorf("at SELECT: expected quoted table name") 160 | } 161 | p.query.TableName = tableName 162 | p.pop() 163 | p.step = stepWhere 164 | case stepInsertTable: 165 | tableName := p.peek() 166 | if len(tableName) == 0 { 167 | return p.query, fmt.Errorf("at INSERT INTO: expected quoted table name") 168 | } 169 | p.query.TableName = tableName 170 | p.pop() 171 | p.step = stepInsertFieldsOpeningParens 172 | case stepDeleteFromTable: 173 | tableName := p.peek() 174 | if len(tableName) == 0 { 175 | return p.query, fmt.Errorf("at DELETE FROM: expected quoted table name") 176 | } 177 | p.query.TableName = tableName 178 | p.pop() 179 | p.step = stepWhere 180 | case stepUpdateTable: 181 | tableName := p.peek() 182 | if len(tableName) == 0 { 183 | return p.query, fmt.Errorf("at UPDATE: expected quoted table name") 184 | } 185 | p.query.TableName = tableName 186 | p.pop() 187 | p.step = stepUpdateSet 188 | case stepUpdateSet: 189 | setRWord := p.peek() 190 | if setRWord != "SET" { 191 | return p.query, fmt.Errorf("at UPDATE: expected 'SET'") 192 | } 193 | p.pop() 194 | p.step = stepUpdateField 195 | case stepUpdateField: 196 | identifier := p.peek() 197 | if !isIdentifier(identifier) { 198 | return p.query, fmt.Errorf("at UPDATE: expected at least one field to update") 199 | } 200 | p.nextUpdateField = identifier 201 | p.pop() 202 | p.step = stepUpdateEquals 203 | case stepUpdateEquals: 204 | equalsRWord := p.peek() 205 | if equalsRWord != "=" { 206 | return p.query, fmt.Errorf("at UPDATE: expected '='") 207 | } 208 | p.pop() 209 | p.step = stepUpdateValue 210 | case stepUpdateValue: 211 | quotedValue, ln := p.peekQuotedStringWithLength() 212 | if ln == 0 { 213 | return p.query, fmt.Errorf("at UPDATE: expected quoted value") 214 | } 215 | p.query.Updates[p.nextUpdateField] = quotedValue 216 | p.nextUpdateField = "" 217 | p.pop() 218 | maybeWhere := p.peek() 219 | if strings.ToUpper(maybeWhere) == "WHERE" { 220 | p.step = stepWhere 221 | continue 222 | } 223 | p.step = stepUpdateComma 224 | case stepUpdateComma: 225 | commaRWord := p.peek() 226 | if commaRWord != "," { 227 | return p.query, fmt.Errorf("at UPDATE: expected ','") 228 | } 229 | p.pop() 230 | p.step = stepUpdateField 231 | case stepWhere: 232 | whereRWord := p.peek() 233 | if strings.ToUpper(whereRWord) != "WHERE" { 234 | return p.query, fmt.Errorf("expected WHERE") 235 | } 236 | p.pop() 237 | p.step = stepWhereField 238 | case stepWhereField: 239 | identifier := p.peek() 240 | if !isIdentifier(identifier) { 241 | return p.query, fmt.Errorf("at WHERE: expected field") 242 | } 243 | p.query.Conditions = append(p.query.Conditions, query.Condition{Operand1: identifier, Operand1IsField: true}) 244 | p.pop() 245 | p.step = stepWhereOperator 246 | case stepWhereOperator: 247 | operator := p.peek() 248 | currentCondition := p.query.Conditions[len(p.query.Conditions)-1] 249 | switch operator { 250 | case "=": 251 | currentCondition.Operator = query.Eq 252 | case ">": 253 | currentCondition.Operator = query.Gt 254 | case ">=": 255 | currentCondition.Operator = query.Gte 256 | case "<": 257 | currentCondition.Operator = query.Lt 258 | case "<=": 259 | currentCondition.Operator = query.Lte 260 | case "!=": 261 | currentCondition.Operator = query.Ne 262 | default: 263 | return p.query, fmt.Errorf("at WHERE: unknown operator") 264 | } 265 | p.query.Conditions[len(p.query.Conditions)-1] = currentCondition 266 | p.pop() 267 | p.step = stepWhereValue 268 | case stepWhereValue: 269 | currentCondition := p.query.Conditions[len(p.query.Conditions)-1] 270 | identifier := p.peek() 271 | if isIdentifier(identifier) { 272 | currentCondition.Operand2 = identifier 273 | currentCondition.Operand2IsField = true 274 | } else { 275 | quotedValue, ln := p.peekQuotedStringWithLength() 276 | if ln == 0 { 277 | return p.query, fmt.Errorf("at WHERE: expected quoted value") 278 | } 279 | currentCondition.Operand2 = quotedValue 280 | currentCondition.Operand2IsField = false 281 | } 282 | p.query.Conditions[len(p.query.Conditions)-1] = currentCondition 283 | p.pop() 284 | p.step = stepWhereAnd 285 | case stepWhereAnd: 286 | andRWord := p.peek() 287 | if strings.ToUpper(andRWord) != "AND" { 288 | return p.query, fmt.Errorf("expected AND") 289 | } 290 | p.pop() 291 | p.step = stepWhereField 292 | case stepInsertFieldsOpeningParens: 293 | openingParens := p.peek() 294 | if len(openingParens) != 1 || openingParens != "(" { 295 | return p.query, fmt.Errorf("at INSERT INTO: expected opening parens") 296 | } 297 | p.pop() 298 | p.step = stepInsertFields 299 | case stepInsertFields: 300 | identifier := p.peek() 301 | if !isIdentifier(identifier) { 302 | return p.query, fmt.Errorf("at INSERT INTO: expected at least one field to insert") 303 | } 304 | p.query.Fields = append(p.query.Fields, identifier) 305 | p.pop() 306 | p.step = stepInsertFieldsCommaOrClosingParens 307 | case stepInsertFieldsCommaOrClosingParens: 308 | commaOrClosingParens := p.peek() 309 | if commaOrClosingParens != "," && commaOrClosingParens != ")" { 310 | return p.query, fmt.Errorf("at INSERT INTO: expected comma or closing parens") 311 | } 312 | p.pop() 313 | if commaOrClosingParens == "," { 314 | p.step = stepInsertFields 315 | continue 316 | } 317 | p.step = stepInsertValuesRWord 318 | case stepInsertValuesRWord: 319 | valuesRWord := p.peek() 320 | if strings.ToUpper(valuesRWord) != "VALUES" { 321 | return p.query, fmt.Errorf("at INSERT INTO: expected 'VALUES'") 322 | } 323 | p.pop() 324 | p.step = stepInsertValuesOpeningParens 325 | case stepInsertValuesOpeningParens: 326 | openingParens := p.peek() 327 | if openingParens != "(" { 328 | return p.query, fmt.Errorf("at INSERT INTO: expected opening parens") 329 | } 330 | p.query.Inserts = append(p.query.Inserts, []string{}) 331 | p.pop() 332 | p.step = stepInsertValues 333 | case stepInsertValues: 334 | quotedValue, ln := p.peekQuotedStringWithLength() 335 | if ln == 0 { 336 | return p.query, fmt.Errorf("at INSERT INTO: expected quoted value") 337 | } 338 | p.query.Inserts[len(p.query.Inserts)-1] = append(p.query.Inserts[len(p.query.Inserts)-1], quotedValue) 339 | p.pop() 340 | p.step = stepInsertValuesCommaOrClosingParens 341 | case stepInsertValuesCommaOrClosingParens: 342 | commaOrClosingParens := p.peek() 343 | if commaOrClosingParens != "," && commaOrClosingParens != ")" { 344 | return p.query, fmt.Errorf("at INSERT INTO: expected comma or closing parens") 345 | } 346 | p.pop() 347 | if commaOrClosingParens == "," { 348 | p.step = stepInsertValues 349 | continue 350 | } 351 | currentInsertRow := p.query.Inserts[len(p.query.Inserts)-1] 352 | if len(currentInsertRow) < len(p.query.Fields) { 353 | return p.query, fmt.Errorf("at INSERT INTO: value count doesn't match field count") 354 | } 355 | p.step = stepInsertValuesCommaBeforeOpeningParens 356 | case stepInsertValuesCommaBeforeOpeningParens: 357 | commaRWord := p.peek() 358 | if strings.ToUpper(commaRWord) != "," { 359 | return p.query, fmt.Errorf("at INSERT INTO: expected comma") 360 | } 361 | p.pop() 362 | p.step = stepInsertValuesOpeningParens 363 | } 364 | } 365 | } 366 | 367 | func (p *parser) peek() string { 368 | peeked, _ := p.peekWithLength() 369 | return peeked 370 | } 371 | 372 | func (p *parser) pop() string { 373 | peeked, len := p.peekWithLength() 374 | p.i += len 375 | p.popWhitespace() 376 | return peeked 377 | } 378 | 379 | func (p *parser) popWhitespace() { 380 | for ; p.i < len(p.sql) && p.sql[p.i] == ' '; p.i++ { 381 | } 382 | } 383 | 384 | var reservedWords = []string{ 385 | "(", ")", ">=", "<=", "!=", ",", "=", ">", "<", "SELECT", "INSERT INTO", "VALUES", "UPDATE", "DELETE FROM", 386 | "WHERE", "FROM", "SET", "AS", 387 | } 388 | 389 | func (p *parser) peekWithLength() (string, int) { 390 | if p.i >= len(p.sql) { 391 | return "", 0 392 | } 393 | for _, rWord := range reservedWords { 394 | token := strings.ToUpper(p.sql[p.i:min(len(p.sql), p.i+len(rWord))]) 395 | if token == rWord { 396 | return token, len(token) 397 | } 398 | } 399 | if p.sql[p.i] == '\'' { // Quoted string 400 | return p.peekQuotedStringWithLength() 401 | } 402 | return p.peekIdentifierWithLength() 403 | } 404 | 405 | func (p *parser) peekQuotedStringWithLength() (string, int) { 406 | if len(p.sql) < p.i || p.sql[p.i] != '\'' { 407 | return "", 0 408 | } 409 | for i := p.i + 1; i < len(p.sql); i++ { 410 | if p.sql[i] == '\'' && p.sql[i-1] != '\\' { 411 | return p.sql[p.i+1 : i], len(p.sql[p.i+1:i]) + 2 // +2 for the two quotes 412 | } 413 | } 414 | return "", 0 415 | } 416 | 417 | func (p *parser) peekIdentifierWithLength() (string, int) { 418 | for i := p.i; i < len(p.sql); i++ { 419 | if matched, _ := regexp.MatchString(`[a-zA-Z0-9_*]`, string(p.sql[i])); !matched { 420 | return p.sql[p.i:i], len(p.sql[p.i:i]) 421 | } 422 | } 423 | return p.sql[p.i:], len(p.sql[p.i:]) 424 | } 425 | 426 | func (p *parser) validate() error { 427 | if len(p.query.Conditions) == 0 && p.step == stepWhereField { 428 | return fmt.Errorf("at WHERE: empty WHERE clause") 429 | } 430 | if p.query.Type == query.UnknownType { 431 | return fmt.Errorf("query type cannot be empty") 432 | } 433 | if p.query.TableName == "" { 434 | return fmt.Errorf("table name cannot be empty") 435 | } 436 | if len(p.query.Conditions) == 0 && (p.query.Type == query.Update || p.query.Type == query.Delete) { 437 | return fmt.Errorf("at WHERE: WHERE clause is mandatory for UPDATE & DELETE") 438 | } 439 | for _, c := range p.query.Conditions { 440 | if c.Operator == query.UnknownOperator { 441 | return fmt.Errorf("at WHERE: condition without operator") 442 | } 443 | if c.Operand1 == "" && c.Operand1IsField { 444 | return fmt.Errorf("at WHERE: condition with empty left side operand") 445 | } 446 | if c.Operand2 == "" && c.Operand2IsField { 447 | return fmt.Errorf("at WHERE: condition with empty right side operand") 448 | } 449 | } 450 | if p.query.Type == query.Insert && len(p.query.Inserts) == 0 { 451 | return fmt.Errorf("at INSERT INTO: need at least one row to insert") 452 | } 453 | if p.query.Type == query.Insert { 454 | for _, i := range p.query.Inserts { 455 | if len(i) != len(p.query.Fields) { 456 | return fmt.Errorf("at INSERT INTO: value count doesn't match field count") 457 | } 458 | } 459 | } 460 | return nil 461 | } 462 | 463 | func (p *parser) logError() { 464 | if p.err == nil { 465 | return 466 | } 467 | fmt.Println(p.sql) 468 | fmt.Println(strings.Repeat(" ", p.i) + "^") 469 | fmt.Println(p.err) 470 | } 471 | 472 | func isIdentifier(s string) bool { 473 | for _, rw := range reservedWords { 474 | if strings.ToUpper(s) == rw { 475 | return false 476 | } 477 | } 478 | matched, _ := regexp.MatchString("[a-zA-Z_][a-zA-Z_0-9]*", s) 479 | return matched 480 | } 481 | 482 | func isIdentifierOrAsterisk(s string) bool { 483 | return isIdentifier(s) || s == "*" 484 | } 485 | 486 | func min(a, b int) int { 487 | if a < b { 488 | return a 489 | } 490 | return b 491 | } 492 | -------------------------------------------------------------------------------- /sql_test.go: -------------------------------------------------------------------------------- 1 | package sqlparser 2 | 3 | import ( 4 | "fmt" 5 | "io/ioutil" 6 | "log" 7 | "os" 8 | "testing" 9 | "text/template" 10 | 11 | "github.com/marianogappa/sqlparser/query" 12 | "github.com/stretchr/testify/require" 13 | ) 14 | 15 | type testCase struct { 16 | Name string 17 | SQL string 18 | Expected query.Query 19 | Err error 20 | } 21 | 22 | type output struct { 23 | NoErrorExamples []testCase 24 | ErrorExamples []testCase 25 | Types []string 26 | Operators []string 27 | } 28 | 29 | func TestSQL(t *testing.T) { 30 | ts := []testCase{ 31 | { 32 | Name: "empty query fails", 33 | SQL: "", 34 | Expected: query.Query{}, 35 | Err: fmt.Errorf("query type cannot be empty"), 36 | }, 37 | { 38 | Name: "SELECT without FROM fails", 39 | SQL: "SELECT", 40 | Expected: query.Query{Type: query.Select}, 41 | Err: fmt.Errorf("table name cannot be empty"), 42 | }, 43 | { 44 | Name: "SELECT without fields fails", 45 | SQL: "SELECT FROM 'a'", 46 | Expected: query.Query{Type: query.Select}, 47 | Err: fmt.Errorf("at SELECT: expected field to SELECT"), 48 | }, 49 | { 50 | Name: "SELECT with comma and empty field fails", 51 | SQL: "SELECT b, FROM 'a'", 52 | Expected: query.Query{Type: query.Select}, 53 | Err: fmt.Errorf("at SELECT: expected field to SELECT"), 54 | }, 55 | { 56 | Name: "SELECT works", 57 | SQL: "SELECT a FROM 'b'", 58 | Expected: query.Query{Type: query.Select, TableName: "b", Fields: []string{"a"}}, 59 | Err: nil, 60 | }, 61 | { 62 | Name: "SELECT works with lowercase", 63 | SQL: "select a fRoM 'b'", 64 | Expected: query.Query{Type: query.Select, TableName: "b", Fields: []string{"a"}}, 65 | Err: nil, 66 | }, 67 | { 68 | Name: "SELECT many fields works", 69 | SQL: "SELECT a, c, d FROM 'b'", 70 | Expected: query.Query{Type: query.Select, TableName: "b", Fields: []string{"a", "c", "d"}}, 71 | Err: nil, 72 | }, 73 | { 74 | Name: "SELECT with alias works", 75 | SQL: "SELECT a as z, b as y, c FROM 'b'", 76 | Expected: query.Query{ 77 | Type: query.Select, 78 | TableName: "b", 79 | Fields: []string{"a", "b", "c"}, 80 | Aliases: map[string]string{ 81 | "a": "z", 82 | "b": "y", 83 | }, 84 | }, 85 | Err: nil, 86 | }, 87 | 88 | { 89 | Name: "SELECT with empty WHERE fails", 90 | SQL: "SELECT a, c, d FROM 'b' WHERE", 91 | Expected: query.Query{Type: query.Select, TableName: "b", Fields: []string{"a", "c", "d"}}, 92 | Err: fmt.Errorf("at WHERE: empty WHERE clause"), 93 | }, 94 | { 95 | Name: "SELECT with WHERE with only operand fails", 96 | SQL: "SELECT a, c, d FROM 'b' WHERE a", 97 | Expected: query.Query{Type: query.Select, TableName: "b", Fields: []string{"a", "c", "d"}}, 98 | Err: fmt.Errorf("at WHERE: condition without operator"), 99 | }, 100 | { 101 | Name: "SELECT with WHERE with = works", 102 | SQL: "SELECT a, c, d FROM 'b' WHERE a = ''", 103 | Expected: query.Query{ 104 | Type: query.Select, 105 | TableName: "b", 106 | Fields: []string{"a", "c", "d"}, 107 | Conditions: []query.Condition{ 108 | {Operand1: "a", Operand1IsField: true, Operator: query.Eq, Operand2: "", Operand2IsField: false}, 109 | }, 110 | }, 111 | Err: nil, 112 | }, 113 | { 114 | Name: "SELECT with WHERE with < works", 115 | SQL: "SELECT a, c, d FROM 'b' WHERE a < '1'", 116 | Expected: query.Query{ 117 | Type: query.Select, 118 | TableName: "b", 119 | Fields: []string{"a", "c", "d"}, 120 | Conditions: []query.Condition{ 121 | {Operand1: "a", Operand1IsField: true, Operator: query.Lt, Operand2: "1", Operand2IsField: false}, 122 | }, 123 | }, 124 | Err: nil, 125 | }, 126 | { 127 | Name: "SELECT with WHERE with <= works", 128 | SQL: "SELECT a, c, d FROM 'b' WHERE a <= '1'", 129 | Expected: query.Query{ 130 | Type: query.Select, 131 | TableName: "b", 132 | Fields: []string{"a", "c", "d"}, 133 | Conditions: []query.Condition{ 134 | {Operand1: "a", Operand1IsField: true, Operator: query.Lte, Operand2: "1", Operand2IsField: false}, 135 | }, 136 | }, 137 | Err: nil, 138 | }, 139 | { 140 | Name: "SELECT with WHERE with > works", 141 | SQL: "SELECT a, c, d FROM 'b' WHERE a > '1'", 142 | Expected: query.Query{ 143 | Type: query.Select, 144 | TableName: "b", 145 | Fields: []string{"a", "c", "d"}, 146 | Conditions: []query.Condition{ 147 | {Operand1: "a", Operand1IsField: true, Operator: query.Gt, Operand2: "1", Operand2IsField: false}, 148 | }, 149 | }, 150 | Err: nil, 151 | }, 152 | { 153 | Name: "SELECT with WHERE with >= works", 154 | SQL: "SELECT a, c, d FROM 'b' WHERE a >= '1'", 155 | Expected: query.Query{ 156 | Type: query.Select, 157 | TableName: "b", 158 | Fields: []string{"a", "c", "d"}, 159 | Conditions: []query.Condition{ 160 | {Operand1: "a", Operand1IsField: true, Operator: query.Gte, Operand2: "1", Operand2IsField: false}, 161 | }, 162 | }, 163 | Err: nil, 164 | }, 165 | { 166 | Name: "SELECT with WHERE with != works", 167 | SQL: "SELECT a, c, d FROM 'b' WHERE a != '1'", 168 | Expected: query.Query{ 169 | Type: query.Select, 170 | TableName: "b", 171 | Fields: []string{"a", "c", "d"}, 172 | Conditions: []query.Condition{ 173 | {Operand1: "a", Operand1IsField: true, Operator: query.Ne, Operand2: "1", Operand2IsField: false}, 174 | }, 175 | }, 176 | Err: nil, 177 | }, 178 | { 179 | Name: "SELECT with WHERE with != works (comparing field against another field)", 180 | SQL: "SELECT a, c, d FROM 'b' WHERE a != b", 181 | Expected: query.Query{ 182 | Type: query.Select, 183 | TableName: "b", 184 | Fields: []string{"a", "c", "d"}, 185 | Conditions: []query.Condition{ 186 | {Operand1: "a", Operand1IsField: true, Operator: query.Ne, Operand2: "b", Operand2IsField: true}, 187 | }, 188 | }, 189 | Err: nil, 190 | }, 191 | { 192 | Name: "SELECT * works", 193 | SQL: "SELECT * FROM 'b'", 194 | Expected: query.Query{ 195 | Type: query.Select, 196 | TableName: "b", 197 | Fields: []string{"*"}, 198 | Conditions: nil, 199 | }, 200 | Err: nil, 201 | }, 202 | { 203 | Name: "SELECT a, * works", 204 | SQL: "SELECT a, * FROM 'b'", 205 | Expected: query.Query{ 206 | Type: query.Select, 207 | TableName: "b", 208 | Fields: []string{"a", "*"}, 209 | Conditions: nil, 210 | }, 211 | Err: nil, 212 | }, 213 | { 214 | Name: "SELECT with WHERE with two conditions using AND works", 215 | SQL: "SELECT a, c, d FROM 'b' WHERE a != '1' AND b = '2'", 216 | Expected: query.Query{ 217 | Type: query.Select, 218 | TableName: "b", 219 | Fields: []string{"a", "c", "d"}, 220 | Conditions: []query.Condition{ 221 | {Operand1: "a", Operand1IsField: true, Operator: query.Ne, Operand2: "1", Operand2IsField: false}, 222 | {Operand1: "b", Operand1IsField: true, Operator: query.Eq, Operand2: "2", Operand2IsField: false}, 223 | }, 224 | }, 225 | Err: nil, 226 | }, 227 | { 228 | Name: "Empty UPDATE fails", 229 | SQL: "UPDATE", 230 | Expected: query.Query{}, 231 | Err: fmt.Errorf("table name cannot be empty"), 232 | }, 233 | { 234 | Name: "Incomplete UPDATE with table name fails", 235 | SQL: "UPDATE 'a'", 236 | Expected: query.Query{}, 237 | Err: fmt.Errorf("at WHERE: WHERE clause is mandatory for UPDATE & DELETE"), 238 | }, 239 | { 240 | Name: "Incomplete UPDATE with table name and SET fails", 241 | SQL: "UPDATE 'a' SET", 242 | Expected: query.Query{}, 243 | Err: fmt.Errorf("at WHERE: WHERE clause is mandatory for UPDATE & DELETE"), 244 | }, 245 | { 246 | Name: "Incomplete UPDATE with table name, SET with a field but no value and WHERE fails", 247 | SQL: "UPDATE 'a' SET b WHERE", 248 | Expected: query.Query{}, 249 | Err: fmt.Errorf("at UPDATE: expected '='"), 250 | }, 251 | { 252 | Name: "Incomplete UPDATE with table name, SET with a field and = but no value and WHERE fails", 253 | SQL: "UPDATE 'a' SET b = WHERE", 254 | Expected: query.Query{}, 255 | Err: fmt.Errorf("at UPDATE: expected quoted value"), 256 | }, 257 | { 258 | Name: "Incomplete UPDATE due to no WHERE clause fails", 259 | SQL: "UPDATE 'a' SET b = 'hello' WHERE", 260 | Expected: query.Query{}, 261 | Err: fmt.Errorf("at WHERE: empty WHERE clause"), 262 | }, 263 | { 264 | Name: "Incomplete UPDATE due incomplete WHERE clause fails", 265 | SQL: "UPDATE 'a' SET b = 'hello' WHERE a", 266 | Expected: query.Query{}, 267 | Err: fmt.Errorf("at WHERE: condition without operator"), 268 | }, 269 | { 270 | Name: "UPDATE works", 271 | SQL: "UPDATE 'a' SET b = 'hello' WHERE a = '1'", 272 | Expected: query.Query{ 273 | Type: query.Update, 274 | TableName: "a", 275 | Updates: map[string]string{"b": "hello"}, 276 | Conditions: []query.Condition{ 277 | {Operand1: "a", Operand1IsField: true, Operator: query.Eq, Operand2: "1", Operand2IsField: false}, 278 | }, 279 | }, 280 | Err: nil, 281 | }, 282 | { 283 | Name: "UPDATE works with simple quote inside", 284 | SQL: "UPDATE 'a' SET b = 'hello\\'world' WHERE a = '1'", 285 | Expected: query.Query{ 286 | Type: query.Update, 287 | TableName: "a", 288 | Updates: map[string]string{"b": "hello\\'world"}, 289 | Conditions: []query.Condition{ 290 | {Operand1: "a", Operand1IsField: true, Operator: query.Eq, Operand2: "1", Operand2IsField: false}, 291 | }, 292 | }, 293 | Err: nil, 294 | }, 295 | { 296 | Name: "UPDATE with multiple SETs works", 297 | SQL: "UPDATE 'a' SET b = 'hello', c = 'bye' WHERE a = '1'", 298 | Expected: query.Query{ 299 | Type: query.Update, 300 | TableName: "a", 301 | Updates: map[string]string{"b": "hello", "c": "bye"}, 302 | Conditions: []query.Condition{ 303 | {Operand1: "a", Operand1IsField: true, Operator: query.Eq, Operand2: "1", Operand2IsField: false}, 304 | }, 305 | }, 306 | Err: nil, 307 | }, 308 | { 309 | Name: "UPDATE with multiple SETs and multiple conditions works", 310 | SQL: "UPDATE 'a' SET b = 'hello', c = 'bye' WHERE a = '1' AND b = '789'", 311 | Expected: query.Query{ 312 | Type: query.Update, 313 | TableName: "a", 314 | Updates: map[string]string{"b": "hello", "c": "bye"}, 315 | Conditions: []query.Condition{ 316 | {Operand1: "a", Operand1IsField: true, Operator: query.Eq, Operand2: "1", Operand2IsField: false}, 317 | {Operand1: "b", Operand1IsField: true, Operator: query.Eq, Operand2: "789", Operand2IsField: false}, 318 | }, 319 | }, 320 | Err: nil, 321 | }, 322 | { 323 | Name: "Empty DELETE fails", 324 | SQL: "DELETE FROM", 325 | Expected: query.Query{}, 326 | Err: fmt.Errorf("table name cannot be empty"), 327 | }, 328 | { 329 | Name: "DELETE without WHERE fails", 330 | SQL: "DELETE FROM 'a'", 331 | Expected: query.Query{}, 332 | Err: fmt.Errorf("at WHERE: WHERE clause is mandatory for UPDATE & DELETE"), 333 | }, 334 | { 335 | Name: "DELETE with empty WHERE fails", 336 | SQL: "DELETE FROM 'a' WHERE", 337 | Expected: query.Query{}, 338 | Err: fmt.Errorf("at WHERE: empty WHERE clause"), 339 | }, 340 | { 341 | Name: "DELETE with WHERE with field but no operator fails", 342 | SQL: "DELETE FROM 'a' WHERE b", 343 | Expected: query.Query{}, 344 | Err: fmt.Errorf("at WHERE: condition without operator"), 345 | }, 346 | { 347 | Name: "DELETE with WHERE works", 348 | SQL: "DELETE FROM 'a' WHERE b = '1'", 349 | Expected: query.Query{ 350 | Type: query.Delete, 351 | TableName: "a", 352 | Conditions: []query.Condition{ 353 | {Operand1: "b", Operand1IsField: true, Operator: query.Eq, Operand2: "1", Operand2IsField: false}, 354 | }, 355 | }, 356 | Err: nil, 357 | }, 358 | { 359 | Name: "Empty INSERT fails", 360 | SQL: "INSERT INTO", 361 | Expected: query.Query{}, 362 | Err: fmt.Errorf("table name cannot be empty"), 363 | }, 364 | { 365 | Name: "INSERT with no rows to insert fails", 366 | SQL: "INSERT INTO 'a'", 367 | Expected: query.Query{}, 368 | Err: fmt.Errorf("at INSERT INTO: need at least one row to insert"), 369 | }, 370 | { 371 | Name: "INSERT with incomplete value section fails", 372 | SQL: "INSERT INTO 'a' (", 373 | Expected: query.Query{}, 374 | Err: fmt.Errorf("at INSERT INTO: need at least one row to insert"), 375 | }, 376 | { 377 | Name: "INSERT with incomplete value section fails #2", 378 | SQL: "INSERT INTO 'a' (b", 379 | Expected: query.Query{}, 380 | Err: fmt.Errorf("at INSERT INTO: need at least one row to insert"), 381 | }, 382 | { 383 | Name: "INSERT with incomplete value section fails #3", 384 | SQL: "INSERT INTO 'a' (b)", 385 | Expected: query.Query{}, 386 | Err: fmt.Errorf("at INSERT INTO: need at least one row to insert"), 387 | }, 388 | { 389 | Name: "INSERT with incomplete value section fails #4", 390 | SQL: "INSERT INTO 'a' (b) VALUES", 391 | Expected: query.Query{}, 392 | Err: fmt.Errorf("at INSERT INTO: need at least one row to insert"), 393 | }, 394 | { 395 | Name: "INSERT with incomplete row fails", 396 | SQL: "INSERT INTO 'a' (b) VALUES (", 397 | Expected: query.Query{}, 398 | Err: fmt.Errorf("at INSERT INTO: value count doesn't match field count"), 399 | }, 400 | { 401 | Name: "INSERT works", 402 | SQL: "INSERT INTO 'a' (b) VALUES ('1')", 403 | Expected: query.Query{ 404 | Type: query.Insert, 405 | TableName: "a", 406 | Fields: []string{"b"}, 407 | Inserts: [][]string{{"1"}}, 408 | }, 409 | Err: nil, 410 | }, 411 | { 412 | Name: "INSERT * fails", 413 | SQL: "INSERT INTO 'a' (*) VALUES ('1')", 414 | Expected: query.Query{}, 415 | Err: fmt.Errorf("at INSERT INTO: expected at least one field to insert"), 416 | }, 417 | { 418 | Name: "INSERT with multiple fields works", 419 | SQL: "INSERT INTO 'a' (b,c, d) VALUES ('1','2' , '3' )", 420 | Expected: query.Query{ 421 | Type: query.Insert, 422 | TableName: "a", 423 | Fields: []string{"b", "c", "d"}, 424 | Inserts: [][]string{{"1", "2", "3"}}, 425 | }, 426 | Err: nil, 427 | }, 428 | { 429 | Name: "INSERT with multiple fields and multiple values works", 430 | SQL: "INSERT INTO 'a' (b,c, d) VALUES ('1','2' , '3' ),('4','5' ,'6' )", 431 | Expected: query.Query{ 432 | Type: query.Insert, 433 | TableName: "a", 434 | Fields: []string{"b", "c", "d"}, 435 | Inserts: [][]string{{"1", "2", "3"}, {"4", "5", "6"}}, 436 | }, 437 | Err: nil, 438 | }, 439 | } 440 | 441 | output := output{Types: query.TypeString, Operators: query.OperatorString} 442 | for _, tc := range ts { 443 | t.Run(tc.Name, func(t *testing.T) { 444 | actual, err := ParseMany([]string{tc.SQL}) 445 | if tc.Err != nil && err == nil { 446 | t.Errorf("Error should have been %v", tc.Err) 447 | } 448 | if tc.Err == nil && err != nil { 449 | t.Errorf("Error should have been nil but was %v", err) 450 | } 451 | if tc.Err != nil && err != nil { 452 | require.Equal(t, tc.Err, err, "Unexpected error") 453 | } 454 | if len(actual) > 0 { 455 | require.Equal(t, tc.Expected, actual[0], "Query didn't match expectation") 456 | } 457 | if tc.Err != nil { 458 | output.ErrorExamples = append(output.ErrorExamples, tc) 459 | } else { 460 | output.NoErrorExamples = append(output.NoErrorExamples, tc) 461 | } 462 | }) 463 | } 464 | createReadme(output) 465 | } 466 | 467 | func createReadme(out output) { 468 | content, err := ioutil.ReadFile("README.template") 469 | if err != nil { 470 | log.Fatal(err) 471 | } 472 | t := template.Must(template.New("").Parse(string(content))) 473 | f, err := os.Create("README.md") 474 | if err != nil { 475 | log.Fatal(err) 476 | } 477 | if err := t.Execute(f, out); err != nil { 478 | log.Fatal(err) 479 | } 480 | } 481 | --------------------------------------------------------------------------------