From 5888fa9c14bceaecd800cb5fabda188ca39f0708 Mon Sep 17 00:00:00 2001 From: XingY Date: Thu, 10 Jul 2025 14:59:51 -0700 Subject: [PATCH 1/6] Fix sql LIKE usage to properly escape special characters --- .../labkey/experiment/api/ExpIdentifiableBaseImpl.java | 9 +++++++-- 1 file changed, 7 insertions(+), 2 deletions(-) diff --git a/experiment/src/org/labkey/experiment/api/ExpIdentifiableBaseImpl.java b/experiment/src/org/labkey/experiment/api/ExpIdentifiableBaseImpl.java index 1ab2e7dacaa..fcd12189ded 100644 --- a/experiment/src/org/labkey/experiment/api/ExpIdentifiableBaseImpl.java +++ b/experiment/src/org/labkey/experiment/api/ExpIdentifiableBaseImpl.java @@ -17,11 +17,13 @@ package org.labkey.experiment.api; import org.jetbrains.annotations.Nullable; +import org.labkey.api.data.CompareType; import org.labkey.api.data.DbScope; import org.labkey.api.data.SQLFragment; import org.labkey.api.data.SqlSelector; import org.labkey.api.data.Table; import org.labkey.api.data.TableInfo; +import org.labkey.api.data.dialect.SqlDialect; import org.labkey.api.exp.IdentifiableBase; import org.labkey.api.exp.Lsid; import org.labkey.api.exp.OntologyManager; @@ -172,14 +174,17 @@ protected Function getMaxCounterWithPrefixFunction(TableInfo table return (namePrefix) -> { long max = 0; + SqlDialect dialect = tableInfo.getSqlDialect(); // Here we don't apply a container filter and instead rely on the "CpasType" of the associated data. // This allows for us to process max counter from all matching results within the provided type. - String prefixLike = namePrefix.toLowerCase() + "%"; // case insensitive + String prefixLike = CompareType.escapeLikePattern(namePrefix, '!') + "%"; SQLFragment sql = new SQLFragment() .append("SELECT Name\n") .append("FROM ").append(tableInfo, "i") - .append(" WHERE i.CpasType = ? AND LOWER(i.NAME) LIKE ?") + .append(" WHERE i.CpasType = ? AND i.NAME ") + .append(dialect.getCaseInsensitiveLikeOperator()) + .append(" ? ESCAPE '!'") .add(dataTypeLsid) .add(prefixLike); From 662dc3e387c67cde4d8a0dff8b8e5bfee50e8d4a Mon Sep 17 00:00:00 2001 From: XingY Date: Sun, 13 Jul 2025 19:16:12 -0700 Subject: [PATCH 2/6] appendCaseInsensitiveStartsWith util --- .../labkey/api/data/dialect/SqlDialect.java | 35 +++++++++++++++++++ .../api/ExpIdentifiableBaseImpl.java | 11 +++--- 2 files changed, 39 insertions(+), 7 deletions(-) diff --git a/api/src/org/labkey/api/data/dialect/SqlDialect.java b/api/src/org/labkey/api/data/dialect/SqlDialect.java index 35eab33eedc..139b8ca07e4 100644 --- a/api/src/org/labkey/api/data/dialect/SqlDialect.java +++ b/api/src/org/labkey/api/data/dialect/SqlDialect.java @@ -27,6 +27,7 @@ import org.labkey.api.collections.CsvSet; import org.labkey.api.collections.Sets; import org.labkey.api.data.ColumnInfo; +import org.labkey.api.data.CompareType; import org.labkey.api.data.ConnectionWrapper; import org.labkey.api.data.CoreSchema; import org.labkey.api.data.DatabaseTableType; @@ -535,6 +536,40 @@ public SQLFragment appendInClauseSql(SQLFragment sql, @NotNull Collection par return DEFAULT_GENERATOR.appendInClauseSql(sql, params); } + public SQLFragment appendCaseInsensitiveLikeClause(SQLFragment sql, @NotNull String matchStr, @Nullable String wildcardPrefix, @Nullable String wildcardSuffix, char escapeChar) + { + String prefix = wildcardPrefix != null ? wildcardPrefix : ""; + String suffix = wildcardSuffix != null ? wildcardSuffix : ""; + String prefixLike = prefix + CompareType.escapeLikePattern(matchStr, escapeChar) + suffix; + String escapeToken = " ESCAPE '" + escapeChar + "'"; + sql.append(" ") + .append(getCaseInsensitiveLikeOperator()) + .append(" ") + .appendValue(prefixLike) + .append(escapeToken); + return sql; + } + + public SQLFragment appendCaseInsensitiveLikeClause(SQLFragment sql, @NotNull String matchStr, @Nullable String wildcardPrefix, @Nullable String wildcardSuffix) + { + return appendCaseInsensitiveLikeClause(sql, matchStr, wildcardPrefix, wildcardSuffix, '!'); + } + + public SQLFragment appendCaseInsensitiveLikeClause(SQLFragment sql, @NotNull String matchStr) + { + return appendCaseInsensitiveLikeClause(sql, matchStr, "%", "%", '!'); + } + + public SQLFragment appendCaseInsensitiveStartsWith(SQLFragment sql, @NotNull String matchStr) + { + return appendCaseInsensitiveLikeClause(sql, matchStr, null, "%", '!'); + } + + public SQLFragment appendCaseInsensitiveEndsWith(SQLFragment sql, @NotNull String matchStr) + { + return appendCaseInsensitiveLikeClause(sql, matchStr, "%", null, '!'); + } + public abstract boolean requiresStatementMaxRows(); /** diff --git a/experiment/src/org/labkey/experiment/api/ExpIdentifiableBaseImpl.java b/experiment/src/org/labkey/experiment/api/ExpIdentifiableBaseImpl.java index fcd12189ded..63ee0169963 100644 --- a/experiment/src/org/labkey/experiment/api/ExpIdentifiableBaseImpl.java +++ b/experiment/src/org/labkey/experiment/api/ExpIdentifiableBaseImpl.java @@ -174,19 +174,16 @@ protected Function getMaxCounterWithPrefixFunction(TableInfo table return (namePrefix) -> { long max = 0; - SqlDialect dialect = tableInfo.getSqlDialect(); // Here we don't apply a container filter and instead rely on the "CpasType" of the associated data. // This allows for us to process max counter from all matching results within the provided type. - String prefixLike = CompareType.escapeLikePattern(namePrefix, '!') + "%"; SQLFragment sql = new SQLFragment() .append("SELECT Name\n") .append("FROM ").append(tableInfo, "i") - .append(" WHERE i.CpasType = ? AND i.NAME ") - .append(dialect.getCaseInsensitiveLikeOperator()) - .append(" ? ESCAPE '!'") - .add(dataTypeLsid) - .add(prefixLike); + .append(" WHERE i.CpasType = ? AND i.NAME") + .add(dataTypeLsid); + + tableInfo.getSqlDialect().appendCaseInsensitiveStartsWith(sql, namePrefix); List names = new SqlSelector(tableInfo.getSchema(), sql).getArrayList(String.class); From 855f809e48c3109ceaaaccc7a2a109427411a6ed Mon Sep 17 00:00:00 2001 From: XingY Date: Tue, 15 Jul 2025 10:11:47 -0700 Subject: [PATCH 3/6] junit tests --- api/src/org/labkey/api/data/dialect/SqlDialect.java | 12 ++++++++++++ 1 file changed, 12 insertions(+) diff --git a/api/src/org/labkey/api/data/dialect/SqlDialect.java b/api/src/org/labkey/api/data/dialect/SqlDialect.java index 139b8ca07e4..9f4cd805f97 100644 --- a/api/src/org/labkey/api/data/dialect/SqlDialect.java +++ b/api/src/org/labkey/api/data/dialect/SqlDialect.java @@ -2145,6 +2145,7 @@ public void testScopes() this.s = scope; this.d = scope.getSqlDialect(); testDialectStringHandler(); + testLikeOperator(); }); } @@ -2171,5 +2172,16 @@ void testDialectStringHandler() for (String v : Arrays.asList("\\b", "\\f", "\\n", "\\r", "\\t", "\\1", "\\22", "\\333", "\\xf", "\\x20", "\\1234", "\\U12345678")) testEquals(v, new SQLFragment("SELECT ").appendStringLiteral(v, d)); } + + void testLikeOperator() + { + assertEquals("SELECT * FROM A WHERE Name " + d.getCaseInsensitiveLikeOperator() + " 'ABC%' ESCAPE '!'", d.appendCaseInsensitiveStartsWith(new SQLFragment("SELECT * FROM A WHERE Name"), "ABC").toDebugString()); + assertEquals("SELECT * FROM A WHERE Name " + d.getCaseInsensitiveLikeOperator() + " 'a!%bc%' ESCAPE '!'", d.appendCaseInsensitiveStartsWith(new SQLFragment("SELECT * FROM A WHERE Name"), "a%bc").toDebugString()); + assertEquals("SELECT * FROM A WHERE Name " + d.getCaseInsensitiveLikeOperator() + " '%ab!_C' ESCAPE '!'", d.appendCaseInsensitiveEndsWith(new SQLFragment("SELECT * FROM A WHERE Name"), "ab_C").toDebugString()); + assertEquals("SELECT * FROM A WHERE Name " + d.getCaseInsensitiveLikeOperator() + " '%a![b]C%' ESCAPE '!'", d.appendCaseInsensitiveLikeClause(new SQLFragment("SELECT * FROM A WHERE Name"), "a[b]C").toDebugString()); + assertEquals("SELECT * FROM A WHERE Name " + d.getCaseInsensitiveLikeOperator() + " 'a![b]C_' ESCAPE '!'", d.appendCaseInsensitiveLikeClause(new SQLFragment("SELECT * FROM A WHERE Name"), "a[b]C", null, "_").toDebugString()); + assertEquals("SELECT * FROM A WHERE Name " + d.getCaseInsensitiveLikeOperator() + " '_a!_![b]C%' ESCAPE '!'", d.appendCaseInsensitiveLikeClause(new SQLFragment("SELECT * FROM A WHERE Name"), "a_[b]C", "_", "%").toDebugString()); + assertEquals("SELECT * FROM A WHERE Name " + d.getCaseInsensitiveLikeOperator() + " '_a[[_[[b]C!d%' ESCAPE '['", d.appendCaseInsensitiveLikeClause(new SQLFragment("SELECT * FROM A WHERE Name"), "a_[b]C!d", "_", "%", '[').toDebugString()); + } } } From b6e16b3d9b38874a0cf229acaa3a82075eddd87b Mon Sep 17 00:00:00 2001 From: XingY Date: Tue, 15 Jul 2025 10:39:21 -0700 Subject: [PATCH 4/6] fix test --- api/src/org/labkey/api/data/dialect/SqlDialect.java | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/api/src/org/labkey/api/data/dialect/SqlDialect.java b/api/src/org/labkey/api/data/dialect/SqlDialect.java index 9f4cd805f97..37ee7d3bb22 100644 --- a/api/src/org/labkey/api/data/dialect/SqlDialect.java +++ b/api/src/org/labkey/api/data/dialect/SqlDialect.java @@ -2181,7 +2181,7 @@ void testLikeOperator() assertEquals("SELECT * FROM A WHERE Name " + d.getCaseInsensitiveLikeOperator() + " '%a![b]C%' ESCAPE '!'", d.appendCaseInsensitiveLikeClause(new SQLFragment("SELECT * FROM A WHERE Name"), "a[b]C").toDebugString()); assertEquals("SELECT * FROM A WHERE Name " + d.getCaseInsensitiveLikeOperator() + " 'a![b]C_' ESCAPE '!'", d.appendCaseInsensitiveLikeClause(new SQLFragment("SELECT * FROM A WHERE Name"), "a[b]C", null, "_").toDebugString()); assertEquals("SELECT * FROM A WHERE Name " + d.getCaseInsensitiveLikeOperator() + " '_a!_![b]C%' ESCAPE '!'", d.appendCaseInsensitiveLikeClause(new SQLFragment("SELECT * FROM A WHERE Name"), "a_[b]C", "_", "%").toDebugString()); - assertEquals("SELECT * FROM A WHERE Name " + d.getCaseInsensitiveLikeOperator() + " '_a[[_[[b]C!d%' ESCAPE '['", d.appendCaseInsensitiveLikeClause(new SQLFragment("SELECT * FROM A WHERE Name"), "a_[b]C!d", "_", "%", '[').toDebugString()); + assertEquals("SELECT * FROM A WHERE Name " + d.getCaseInsensitiveLikeOperator() + " '_a[[[]_[[b]C!d%' ESCAPE '['", d.appendCaseInsensitiveLikeClause(new SQLFragment("SELECT * FROM A WHERE Name"), "a_[b]C!d", "_", "%", '[').toDebugString()); } } } From d8f0766568edb8321713cc381a960e5e8baab830 Mon Sep 17 00:00:00 2001 From: XingY Date: Tue, 15 Jul 2025 11:15:52 -0700 Subject: [PATCH 5/6] fix test --- api/src/org/labkey/api/data/dialect/SqlDialect.java | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/api/src/org/labkey/api/data/dialect/SqlDialect.java b/api/src/org/labkey/api/data/dialect/SqlDialect.java index 37ee7d3bb22..266056fd4b2 100644 --- a/api/src/org/labkey/api/data/dialect/SqlDialect.java +++ b/api/src/org/labkey/api/data/dialect/SqlDialect.java @@ -2181,7 +2181,7 @@ void testLikeOperator() assertEquals("SELECT * FROM A WHERE Name " + d.getCaseInsensitiveLikeOperator() + " '%a![b]C%' ESCAPE '!'", d.appendCaseInsensitiveLikeClause(new SQLFragment("SELECT * FROM A WHERE Name"), "a[b]C").toDebugString()); assertEquals("SELECT * FROM A WHERE Name " + d.getCaseInsensitiveLikeOperator() + " 'a![b]C_' ESCAPE '!'", d.appendCaseInsensitiveLikeClause(new SQLFragment("SELECT * FROM A WHERE Name"), "a[b]C", null, "_").toDebugString()); assertEquals("SELECT * FROM A WHERE Name " + d.getCaseInsensitiveLikeOperator() + " '_a!_![b]C%' ESCAPE '!'", d.appendCaseInsensitiveLikeClause(new SQLFragment("SELECT * FROM A WHERE Name"), "a_[b]C", "_", "%").toDebugString()); - assertEquals("SELECT * FROM A WHERE Name " + d.getCaseInsensitiveLikeOperator() + " '_a[[[]_[[b]C!d%' ESCAPE '['", d.appendCaseInsensitiveLikeClause(new SQLFragment("SELECT * FROM A WHERE Name"), "a_[b]C!d", "_", "%", '[').toDebugString()); + assertEquals("SELECT * FROM A WHERE Name " + d.getCaseInsensitiveLikeOperator() + " '_a[_[[b]C!d%' ESCAPE '['", d.appendCaseInsensitiveLikeClause(new SQLFragment("SELECT * FROM A WHERE Name"), "a_[b]C!d", "_", "%", '[').toDebugString()); } } } From cb0b41b04d5a9c6fb8ffe365cd34e8cdf1403c0f Mon Sep 17 00:00:00 2001 From: XingY Date: Tue, 15 Jul 2025 11:54:22 -0700 Subject: [PATCH 6/6] fix sql server --- .../org/labkey/api/data/dialect/SqlDialect.java | 15 ++++++++------- 1 file changed, 8 insertions(+), 7 deletions(-) diff --git a/api/src/org/labkey/api/data/dialect/SqlDialect.java b/api/src/org/labkey/api/data/dialect/SqlDialect.java index 266056fd4b2..537929ef88e 100644 --- a/api/src/org/labkey/api/data/dialect/SqlDialect.java +++ b/api/src/org/labkey/api/data/dialect/SqlDialect.java @@ -2175,13 +2175,14 @@ void testDialectStringHandler() void testLikeOperator() { - assertEquals("SELECT * FROM A WHERE Name " + d.getCaseInsensitiveLikeOperator() + " 'ABC%' ESCAPE '!'", d.appendCaseInsensitiveStartsWith(new SQLFragment("SELECT * FROM A WHERE Name"), "ABC").toDebugString()); - assertEquals("SELECT * FROM A WHERE Name " + d.getCaseInsensitiveLikeOperator() + " 'a!%bc%' ESCAPE '!'", d.appendCaseInsensitiveStartsWith(new SQLFragment("SELECT * FROM A WHERE Name"), "a%bc").toDebugString()); - assertEquals("SELECT * FROM A WHERE Name " + d.getCaseInsensitiveLikeOperator() + " '%ab!_C' ESCAPE '!'", d.appendCaseInsensitiveEndsWith(new SQLFragment("SELECT * FROM A WHERE Name"), "ab_C").toDebugString()); - assertEquals("SELECT * FROM A WHERE Name " + d.getCaseInsensitiveLikeOperator() + " '%a![b]C%' ESCAPE '!'", d.appendCaseInsensitiveLikeClause(new SQLFragment("SELECT * FROM A WHERE Name"), "a[b]C").toDebugString()); - assertEquals("SELECT * FROM A WHERE Name " + d.getCaseInsensitiveLikeOperator() + " 'a![b]C_' ESCAPE '!'", d.appendCaseInsensitiveLikeClause(new SQLFragment("SELECT * FROM A WHERE Name"), "a[b]C", null, "_").toDebugString()); - assertEquals("SELECT * FROM A WHERE Name " + d.getCaseInsensitiveLikeOperator() + " '_a!_![b]C%' ESCAPE '!'", d.appendCaseInsensitiveLikeClause(new SQLFragment("SELECT * FROM A WHERE Name"), "a_[b]C", "_", "%").toDebugString()); - assertEquals("SELECT * FROM A WHERE Name " + d.getCaseInsensitiveLikeOperator() + " '_a[_[[b]C!d%' ESCAPE '['", d.appendCaseInsensitiveLikeClause(new SQLFragment("SELECT * FROM A WHERE Name"), "a_[b]C!d", "_", "%", '[').toDebugString()); + String stringLiteralPrefix = d.isSqlServer() ? " N" : " "; + assertEquals("SELECT * FROM A WHERE Name " + d.getCaseInsensitiveLikeOperator() + stringLiteralPrefix + "'ABC%' ESCAPE '!'", d.appendCaseInsensitiveStartsWith(new SQLFragment("SELECT * FROM A WHERE Name"), "ABC").toDebugString()); + assertEquals("SELECT * FROM A WHERE Name " + d.getCaseInsensitiveLikeOperator() + stringLiteralPrefix + "'a!%bc%' ESCAPE '!'", d.appendCaseInsensitiveStartsWith(new SQLFragment("SELECT * FROM A WHERE Name"), "a%bc").toDebugString()); + assertEquals("SELECT * FROM A WHERE Name " + d.getCaseInsensitiveLikeOperator() + stringLiteralPrefix + "'%ab!_C' ESCAPE '!'", d.appendCaseInsensitiveEndsWith(new SQLFragment("SELECT * FROM A WHERE Name"), "ab_C").toDebugString()); + assertEquals("SELECT * FROM A WHERE Name " + d.getCaseInsensitiveLikeOperator() + stringLiteralPrefix + "'%a![b]C%' ESCAPE '!'", d.appendCaseInsensitiveLikeClause(new SQLFragment("SELECT * FROM A WHERE Name"), "a[b]C").toDebugString()); + assertEquals("SELECT * FROM A WHERE Name " + d.getCaseInsensitiveLikeOperator() + stringLiteralPrefix + "'a![b]C_' ESCAPE '!'", d.appendCaseInsensitiveLikeClause(new SQLFragment("SELECT * FROM A WHERE Name"), "a[b]C", null, "_").toDebugString()); + assertEquals("SELECT * FROM A WHERE Name " + d.getCaseInsensitiveLikeOperator() + stringLiteralPrefix + "'_a!_![b]C%' ESCAPE '!'", d.appendCaseInsensitiveLikeClause(new SQLFragment("SELECT * FROM A WHERE Name"), "a_[b]C", "_", "%").toDebugString()); + assertEquals("SELECT * FROM A WHERE Name " + d.getCaseInsensitiveLikeOperator() + stringLiteralPrefix + "'_a[_[[b]C!d%' ESCAPE '['", d.appendCaseInsensitiveLikeClause(new SQLFragment("SELECT * FROM A WHERE Name"), "a_[b]C!d", "_", "%", '[').toDebugString()); } } }