From a09454accf27f5a1a5f9d7cd99ae546cfbedfd34 Mon Sep 17 00:00:00 2001 From: John Guo Date: Mon, 16 Dec 2024 11:17:47 +0800 Subject: [PATCH] feat(contrib/drivers/mssql): enable unit testing (#4043) --- .github/workflows/ci-main.yml | 15 +++--- contrib/drivers/mssql/mssql_do_filter.go | 50 +++++++++++++------ contrib/drivers/mssql/mssql_do_filter_test.go | 15 +++--- .../drivers/mssql/mssql_z_unit_basic_test.go | 4 +- .../drivers/mssql/mssql_z_unit_init_test.go | 15 ++---- .../drivers/mssql/mssql_z_unit_model_test.go | 1 - 6 files changed, 56 insertions(+), 44 deletions(-) diff --git a/.github/workflows/ci-main.yml b/.github/workflows/ci-main.yml index 6eeee5dd9ac..ecbd084c67f 100644 --- a/.github/workflows/ci-main.yml +++ b/.github/workflows/ci-main.yml @@ -109,22 +109,19 @@ jobs: # -p 1433:1433 \ # -e ACCEPT_EULA=Y \ # -e SA_PASSWORD=LoremIpsum86 \ - # -e MSSQL_DB=test \ # -e MSSQL_USER=root \ # -e MSSQL_PASSWORD=LoremIpsum86 \ - # loads/mssqldocker:14.0.3391.2 + # mcr.microsoft.com/mssql/server:2022-latest mssql: - image: loads/mssqldocker:14.0.3391.2 + image: mcr.microsoft.com/mssql/server:2022-latest env: - ACCEPT_EULA: Y - SA_PASSWORD: LoremIpsum86 - MSSQL_DB: test - MSSQL_USER: root - MSSQL_PASSWORD: LoremIpsum86 + TZ: Asia/Shanghai + ACCEPT_EULA: Y + MSSQL_SA_PASSWORD: LoremIpsum86 ports: - 1433:1433 options: >- - --health-cmd="/opt/mssql-tools/bin/sqlcmd -S localhost -U sa -P LoremIpsum86 -l 30 -Q \"SELECT 1\" || exit 1" + --health-cmd="/opt/mssql-tools18/bin/sqlcmd -S localhost -U sa -P ${MSSQL_SA_PASSWORD} -N -C -l 30 -Q \"SELECT 1\" || exit 1" --health-start-period 10s --health-interval 10s --health-timeout 5s diff --git a/contrib/drivers/mssql/mssql_do_filter.go b/contrib/drivers/mssql/mssql_do_filter.go index f6e4538bddb..6130b9e795e 100644 --- a/contrib/drivers/mssql/mssql_do_filter.go +++ b/contrib/drivers/mssql/mssql_do_filter.go @@ -18,12 +18,18 @@ import ( ) var ( - orderBySqlTmp = `SELECT %s %s OFFSET %d ROWS FETCH NEXT %d ROWS ONLY` - withoutOrderBySqlTmp = `SELECT %s OFFSET %d ROWS FETCH NEXT %d ROWS ONLY` selectWithOrderSqlTmp = ` -SELECT * FROM (SELECT ROW_NUMBER() OVER (ORDER BY %s) as ROW_NUMBER__, %s ) as TMP_ -WHERE TMP_.ROW_NUMBER__ > %d AND TMP_.ROW_NUMBER__ <= %d -` +SELECT * FROM ( + SELECT ROW_NUMBER() OVER (ORDER BY %s) as ROW_NUMBER__, %s + FROM (%s) as InnerQuery +) as TMP_ +WHERE TMP_.ROW_NUMBER__ > %d AND TMP_.ROW_NUMBER__ <= %d` + selectWithoutOrderSqlTmp = ` +SELECT * FROM ( + SELECT ROW_NUMBER() OVER (ORDER BY (SELECT NULL)) as ROW_NUMBER__, %s + FROM (%s) as InnerQuery +) as TMP_ +WHERE TMP_.ROW_NUMBER__ > %d AND TMP_.ROW_NUMBER__ <= %d` ) func init() { @@ -32,6 +38,10 @@ func init() { if err != nil { panic(err) } + selectWithoutOrderSqlTmp, err = gdb.FormatMultiLineSqlToSingle(selectWithoutOrderSqlTmp) + if err != nil { + panic(err) + } } // DoFilter deals with the sql string before commits it to underlying sql driver. @@ -98,14 +108,19 @@ func (d *Driver) handleSelectSqlReplacement(toBeCommittedSql string) (newSql str return "", err } - // SELECT and ORDER BY + // Extract SELECT part selectStr := strings.TrimSpace(allMatch[1]) + + // Extract ORDER BY part orderStr := "" if len(allMatch[2]) > 0 { orderStr = strings.TrimSpace(allMatch[2]) + // Remove "ORDER BY" prefix as it will be used in OVER clause + orderStr = strings.TrimPrefix(orderStr, "ORDER BY") + orderStr = strings.TrimSpace(orderStr) } - // LIMIT and OFFSET value + // Calculate LIMIT and OFFSET values first, _ := strconv.Atoi(allMatch[3]) // LIMIT first parameter limit := 0 if len(allMatch) > 4 && allMatch[4] != "" { @@ -115,19 +130,26 @@ func (d *Driver) handleSelectSqlReplacement(toBeCommittedSql string) (newSql str first = 0 } + // Build the final query if orderStr != "" { - // have ORDER BY clause + // Have ORDER BY clause newSql = fmt.Sprintf( - orderBySqlTmp, - selectStr, orderStr, first, limit, + selectWithOrderSqlTmp, + orderStr, // ORDER BY clause for ROW_NUMBER + "*", // Select all columns + fmt.Sprintf("SELECT %s", selectStr), // Original SELECT + first, // OFFSET + first+limit, // OFFSET + LIMIT ) } else { - // without ORDER BY clause + // Without ORDER BY clause newSql = fmt.Sprintf( - withoutOrderBySqlTmp, - selectStr, first, limit, + selectWithoutOrderSqlTmp, + "*", // Select all columns + fmt.Sprintf("SELECT %s", selectStr), // Original SELECT + first, // OFFSET + first+limit, // OFFSET + LIMIT ) } - return newSql, nil } diff --git a/contrib/drivers/mssql/mssql_do_filter_test.go b/contrib/drivers/mssql/mssql_do_filter_test.go index 91ded572382..24e2c80e9ed 100644 --- a/contrib/drivers/mssql/mssql_do_filter_test.go +++ b/contrib/drivers/mssql/mssql_do_filter_test.go @@ -54,7 +54,6 @@ func TestDriver_DoFilter(t *testing.T) { } func TestDriver_handleSelectSqlReplacement(t *testing.T) { - gtest.C(t, func(t *gtest.T) { d := &Driver{} @@ -67,7 +66,7 @@ func TestDriver_handleSelectSqlReplacement(t *testing.T) { // LIMIT query with offset and number of rows inputSql = "SELECT * FROM User ORDER BY ID DESC LIMIT 100, 200" - expectedSql = "SELECT * FROM User ORDER BY ID DESC OFFSET 100 ROWS FETCH NEXT 200 ROWS ONLY" + expectedSql = "SELECT * FROM ( SELECT ROW_NUMBER() OVER (ORDER BY ID DESC) as ROW_NUMBER__, * FROM (SELECT * FROM User) as InnerQuery ) as TMP_ WHERE TMP_.ROW_NUMBER__ > 100 AND TMP_.ROW_NUMBER__ <= 300" resultSql, err = d.handleSelectSqlReplacement(inputSql) t.AssertNil(err) t.Assert(resultSql, expectedSql) @@ -88,42 +87,42 @@ func TestDriver_handleSelectSqlReplacement(t *testing.T) { // LIMIT query with only rows inputSql = "SELECT * FROM User LIMIT 50" - expectedSql = "SELECT * FROM User OFFSET 0 ROWS FETCH NEXT 50 ROWS ONLY" + expectedSql = "SELECT * FROM ( SELECT ROW_NUMBER() OVER (ORDER BY (SELECT NULL)) as ROW_NUMBER__, * FROM (SELECT * FROM User) as InnerQuery ) as TMP_ WHERE TMP_.ROW_NUMBER__ > 0 AND TMP_.ROW_NUMBER__ <= 50" resultSql, err = d.handleSelectSqlReplacement(inputSql) t.AssertNil(err) t.Assert(resultSql, expectedSql) // LIMIT query without ORDER BY inputSql = "SELECT * FROM User LIMIT 30" - expectedSql = "SELECT * FROM User OFFSET 0 ROWS FETCH NEXT 30 ROWS ONLY" + expectedSql = "SELECT * FROM ( SELECT ROW_NUMBER() OVER (ORDER BY (SELECT NULL)) as ROW_NUMBER__, * FROM (SELECT * FROM User) as InnerQuery ) as TMP_ WHERE TMP_.ROW_NUMBER__ > 0 AND TMP_.ROW_NUMBER__ <= 30" resultSql, err = d.handleSelectSqlReplacement(inputSql) t.AssertNil(err) t.Assert(resultSql, expectedSql) // Complex query with ORDER BY and LIMIT inputSql = "SELECT name, age FROM User WHERE age > 18 ORDER BY age ASC LIMIT 10, 5" - expectedSql = "SELECT name, age FROM User WHERE age > 18 ORDER BY age ASC OFFSET 10 ROWS FETCH NEXT 5 ROWS ONLY" + expectedSql = "SELECT * FROM ( SELECT ROW_NUMBER() OVER (ORDER BY age ASC) as ROW_NUMBER__, * FROM (SELECT name, age FROM User WHERE age > 18) as InnerQuery ) as TMP_ WHERE TMP_.ROW_NUMBER__ > 10 AND TMP_.ROW_NUMBER__ <= 15" resultSql, err = d.handleSelectSqlReplacement(inputSql) t.AssertNil(err) t.Assert(resultSql, expectedSql) // Complex conditional queries have limits inputSql = "SELECT * FROM User WHERE age > 18 AND status = 'active' LIMIT 100, 50" - expectedSql = "SELECT * FROM User WHERE age > 18 AND status = 'active' OFFSET 100 ROWS FETCH NEXT 50 ROWS ONLY" + expectedSql = "SELECT * FROM ( SELECT ROW_NUMBER() OVER (ORDER BY (SELECT NULL)) as ROW_NUMBER__, * FROM (SELECT * FROM User WHERE age > 18 AND status = 'active') as InnerQuery ) as TMP_ WHERE TMP_.ROW_NUMBER__ > 100 AND TMP_.ROW_NUMBER__ <= 150" resultSql, err = d.handleSelectSqlReplacement(inputSql) t.AssertNil(err) t.Assert(resultSql, expectedSql) // A LIMIT query that contains subquery inputSql = "SELECT * FROM (SELECT * FROM User WHERE age > 18) AS subquery LIMIT 10" - expectedSql = "SELECT * FROM (SELECT * FROM User WHERE age > 18) AS subquery OFFSET 0 ROWS FETCH NEXT 10 ROWS ONLY" + expectedSql = "SELECT * FROM ( SELECT ROW_NUMBER() OVER (ORDER BY (SELECT NULL)) as ROW_NUMBER__, * FROM (SELECT * FROM (SELECT * FROM User WHERE age > 18) AS subquery) as InnerQuery ) as TMP_ WHERE TMP_.ROW_NUMBER__ > 0 AND TMP_.ROW_NUMBER__ <= 10" resultSql, err = d.handleSelectSqlReplacement(inputSql) t.AssertNil(err) t.Assert(resultSql, expectedSql) // Queries with complex ORDER BY and LIMIT inputSql = "SELECT name, age FROM User WHERE age > 18 ORDER BY age DESC, name ASC LIMIT 20, 10" - expectedSql = "SELECT name, age FROM User WHERE age > 18 ORDER BY age DESC, name ASC OFFSET 20 ROWS FETCH NEXT 10 ROWS ONLY" + expectedSql = "SELECT * FROM ( SELECT ROW_NUMBER() OVER (ORDER BY age DESC, name ASC) as ROW_NUMBER__, * FROM (SELECT name, age FROM User WHERE age > 18) as InnerQuery ) as TMP_ WHERE TMP_.ROW_NUMBER__ > 20 AND TMP_.ROW_NUMBER__ <= 30" resultSql, err = d.handleSelectSqlReplacement(inputSql) t.AssertNil(err) t.Assert(resultSql, expectedSql) diff --git a/contrib/drivers/mssql/mssql_z_unit_basic_test.go b/contrib/drivers/mssql/mssql_z_unit_basic_test.go index f00e6c84713..7235f0b1653 100644 --- a/contrib/drivers/mssql/mssql_z_unit_basic_test.go +++ b/contrib/drivers/mssql/mssql_z_unit_basic_test.go @@ -42,7 +42,7 @@ func TestTables(t *testing.T) { gtest.AssertEQ(find, true) } - result, err = db.Tables(context.Background(), "test") + result, err = db.Tables(context.Background(), "master") gtest.AssertNil(err) for i := 0; i < len(tables); i++ { find := false @@ -88,7 +88,7 @@ func TestTableFields(t *testing.T) { gtest.AssertEQ(res[k].Comment, v[5]) } - res, err = db.TableFields(context.Background(), "t_user", "test") + res, err = db.TableFields(context.Background(), "t_user", "master") gtest.AssertNil(err) for k, v := range expect { diff --git a/contrib/drivers/mssql/mssql_z_unit_init_test.go b/contrib/drivers/mssql/mssql_z_unit_init_test.go index eec9b76fe68..08e925c5a40 100644 --- a/contrib/drivers/mssql/mssql_z_unit_init_test.go +++ b/contrib/drivers/mssql/mssql_z_unit_init_test.go @@ -25,14 +25,9 @@ var ( ) const ( - TableSize = 10 - TableName = "t_user" - TestSchema1 = "test1" - TestSchema2 = "test2" - TableNamePrefix1 = "gf_" - TestDbUser = "sa" - TestDbPass = "LoremIpsum86" - CreateTime = "2018-10-24 10:00:00" + TableSize = 10 + TestDbUser = "sa" + TestDbPass = "LoremIpsum86" ) func init() { @@ -41,7 +36,7 @@ func init() { Port: "1433", User: TestDbUser, Pass: TestDbPass, - Name: "test", + Name: "master", Type: "mssql", Role: "master", Charset: "utf8", @@ -52,7 +47,7 @@ func init() { nodeLink := gdb.ConfigNode{ Type: "mssql", - Name: "test", + Name: "master", Link: fmt.Sprintf( "mssql:%s:%s@tcp(%s:%s)/%s?encrypt=disable", node.User, node.Pass, node.Host, node.Port, node.Name, diff --git a/contrib/drivers/mssql/mssql_z_unit_model_test.go b/contrib/drivers/mssql/mssql_z_unit_model_test.go index 14d315600ca..6fff5e30f17 100644 --- a/contrib/drivers/mssql/mssql_z_unit_model_test.go +++ b/contrib/drivers/mssql/mssql_z_unit_model_test.go @@ -51,7 +51,6 @@ func Test_Page(t *testing.T) { t.AssertNil(err) gtest.Assert(len(result), 3) }) - } func Test_Model_Insert(t *testing.T) {