Skip to content
74 changes: 74 additions & 0 deletions api/src/org/labkey/api/data/dialect/SqlDialect.java
Original file line number Diff line number Diff line change
Expand Up @@ -2133,6 +2133,80 @@ public record Sequence(String schemaName, String tableName, String columnName, L
return rs.getString("FILTER_CONDITION");
}



//
// ARRAY SUPPORT
//

public boolean supportsArrays()
{
return false;
}

// construct a sql array from SQLFragment elements
public SQLFragment array_construct(SQLFragment[] elements)
{
assert !supportsArrays();
throw new UnsupportedOperationException(getClass().getSimpleName() + " does not implement");
}

// element a is in array b
public SQLFragment element_in_array(SQLFragment a, SQLFragment b)
{
assert !supportsArrays();
throw new UnsupportedOperationException(getClass().getSimpleName() + " does not implement");
}

// element a is not in array b
public SQLFragment element_not_in_array(SQLFragment a, SQLFragment b)
{
assert !supportsArrays();
throw new UnsupportedOperationException(getClass().getSimpleName() + " does not implement");
}

// SET OPERATORS FOR ARRAY TYPE

// all elements of array a are contained in array b
public SQLFragment array_all_in_array(SQLFragment a, SQLFragment b)
{
assert !supportsArrays();
throw new UnsupportedOperationException(getClass().getSimpleName() + " does not implement");
}

// some elements of array a are contained in array b
public SQLFragment array_some_in_array(SQLFragment a, SQLFragment b)
{
assert !supportsArrays();
throw new UnsupportedOperationException(getClass().getSimpleName() + " does not implement");
}

// no elements of array a are contained in array b
public SQLFragment array_none_in_array(SQLFragment a, SQLFragment b)
{
assert !supportsArrays();
throw new UnsupportedOperationException(getClass().getSimpleName() + " does not implement");
}

// arrays a and b contain the same elements equivalent to (A all in B) AND (B all in A)
public SQLFragment array_same_array(SQLFragment a, SQLFragment b)
{
assert !supportsArrays();
throw new UnsupportedOperationException(getClass().getSimpleName() + " does not implement");
}

// array a and array b do not contain the same elements
public SQLFragment array_not_same_array(SQLFragment a, SQLFragment b)
{
assert !supportsArrays();
throw new UnsupportedOperationException(getClass().getSimpleName() + " does not implement");
}
Comment on lines +2147 to +2203
Copy link

Copilot AI Dec 9, 2025

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

The comments for these public API methods should use proper Javadoc format with /** instead of // for better documentation generation. Consider using proper Javadoc like:

/**
 * Construct a SQL array from SQLFragment elements.
 * @param elements The elements to include in the array
 * @return SQLFragment representing the array construction
 */

Copilot uses AI. Check for mistakes.


//
// TESTS
//

public static class DialectTestCase
{
DbScope s;
Expand Down
102 changes: 102 additions & 0 deletions core/src/org/labkey/core/dialect/PostgreSql92Dialect.java
Original file line number Diff line number Diff line change
Expand Up @@ -280,4 +280,106 @@ AND d.deptype IN ('a', 'i') -- Automatic dependency for DEFAULT or index-related
);
return new SqlSelector(table.getSchema(), sql).getCollection(Sequence.class);
}


//
// ARRAY and SET syntax
//

// NOTE LabKey currently does not support ARRAY[VARCHAR], use ARRAY[text] instead
//
// Postgres string literals can be auto-cast to both VARCHAR and TEXT. These all work
// 'color' = 'color'::varchar
// 'color' = 'color'::text
// ARRAY['color'] = ARRAY['color'::text];
// However, ARRAY[text] cannot be auto cast to ARRAY[varchar]
// ARRAY['color'] = ARRAY['color'::varchar]; -- ERROR!
//


@Override
public boolean supportsArrays()
{
return true;
}

@Override
public SQLFragment array_construct(SQLFragment[] elements)
{
SQLFragment ret = new SQLFragment();
ret.append("ARRAY[");
String separator = "";
for (SQLFragment element : elements)
{
ret.append(separator);
ret.append(element);
Copy link
Contributor

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Is there special encoding needed? For example a'b needs to be encoded into a''b?

Copy link
Contributor Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Any encoding should be handled by whoever generated the elements. Those should be correct SQL already.

separator = ", ";
}
ret.append("]");
Copy link
Contributor

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Do we always assume text[] type? I don't think this works for varchar[]. If the column is of type varchar[], the column needs to be casted to text[] first for the comparators to work:
SELECT * from vehicle.colors where tagsvarchar::text[] @> ARRAY['pastel', 'primary'];

Copy link
Contributor Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Good question... We assume that any array we create would be text, and I think we an require that for module created tables as well. It would be tricky for us to handle varchar (say for attached schemas). Currently we don't track varchar and text separately they tend to just get merged as JdbcType.VARCHAR.

Worth adding a comment.

Copy link
Contributor Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

I wonder what happens when using VARCHAR columns e.g

tagsvarchar::text[] @> ARRAY[varcharColumn1, varcharColumn2'];

Copy link
Contributor Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Maybe we need a TEXTARRAY() method? I'll think about it.

return ret;
}

@Override
public SQLFragment array_all_in_array(SQLFragment a, SQLFragment b)
{
SQLFragment ret = new SQLFragment();
ret.append("(").append(a).append(") <@ (").append(b).append(")");
return ret;
}

@Override
public SQLFragment array_some_in_array(SQLFragment a, SQLFragment b)
{
SQLFragment ret = new SQLFragment();
ret.append("(").append(a).append(") && (").append(b).append(")");
return ret;
}

@Override
public SQLFragment array_none_in_array(SQLFragment a, SQLFragment b)
{
return new SQLFragment(" NOT (").append(array_some_in_array(a, b)).append(")");
Copy link
Contributor

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Should array_none_in_array also return empty values?

}

@Override
public SQLFragment array_same_array(SQLFragment a, SQLFragment b)
{
SQLFragment ret = new SQLFragment();
ret.append(array_all_in_array(a, b)).append(" AND ").append(array_all_in_array(b, a));
return ret;
}

@Override
public SQLFragment array_not_same_array(SQLFragment a, SQLFragment b)
{
SQLFragment ret = new SQLFragment();
ret.append("NOT (").append(array_all_in_array(a, b)).append(") OR NOT (").append(array_all_in_array(b, a)).append(")");
return ret;
}

@Override
public SQLFragment element_in_array(SQLFragment a, SQLFragment b)
{
SQLFragment ret = new SQLFragment();
ret.append("(").append(a).append(")");
// DOCs imply that IS NOT DISTINCT FROM ANY should work, but it doesn't???
// ret.append(" IS NOT DISTINCT FROM ANY(");
ret.append(" = ANY(");
ret.append(b);
ret.append(")");
return ret;
}

@Override
public SQLFragment element_not_in_array(SQLFragment a, SQLFragment b)
{
SQLFragment ret = new SQLFragment();
ret.append("(").append(a).append(")");
// DOCs imply that IS NOT DISTINCT FROM ANY should work, but it doesn't???
// ret.append(" IS DISTINCT FROM ALL(");
ret.append(" <> ALL(");
ret.append(b);
ret.append(")");
return ret;
}
}
110 changes: 110 additions & 0 deletions query/src/org/labkey/query/QueryTestCase.jsp
Original file line number Diff line number Diff line change
Expand Up @@ -79,6 +79,8 @@
<%@ page import="static java.util.Objects.requireNonNull" %>
<%@ page import="static java.util.Objects.requireNonNull" %>
<%@ page import="org.labkey.api.query.FieldKey" %>
<%@ page import="org.labkey.api.data.SqlSelector" %>
<%@ page import="org.labkey.api.data.DbScope" %>
<%@ page extends="org.labkey.api.jsp.JspTest.DRT" %>
<%!

Expand Down Expand Up @@ -1134,6 +1136,7 @@ d,seven,twelve,day,month,date,duration,guid
private final String hash = GUID.makeHash();

private QuerySchema lists;
private SqlDialect dialect;

@Before
public void setUp()
Expand All @@ -1142,6 +1145,7 @@ d,seven,twelve,day,month,date,duration,guid
assertNotNull(QueryService.get().getEnvironment(QueryService.Environment.USER));
assertNotNull(QueryService.get().getEnvironment(QueryService.Environment.CONTAINER));
Assume.assumeTrue(getClass().getSimpleName() + " requires list module", ListService.get() != null);
dialect = CoreSchema.getInstance().getSqlDialect();
}


Expand Down Expand Up @@ -1860,4 +1864,110 @@ d,seven,twelve,day,month,date,duration,guid
Assert.fail("Involved column '" + expectedColumn + "' not found for sql:\n" + sql);
}
}

Boolean booleanSelect(SQLFragment s)
{
SQLFragment select = new SQLFragment("SELECT ").append(s);
return new SqlSelector(DbScope.getLabKeyScope(), select).getObject(Boolean.class);
}

SQLFragment array(String... strings)
{
var args = Arrays.stream(strings).map(SQLFragment::unsafe).toList().toArray(new SQLFragment[0]);
return dialect.array_construct(args);
}

@Test
public void testDialectArrayMethods()
{
if (!dialect.supportsArrays())
return;

var elNull = new SQLFragment("NULL");
var elA = new SQLFragment("'A'");
var elB = new SQLFragment("'B'");

assertTrue( booleanSelect(dialect.element_in_array( elA, array("'A'", "'B'") )));
assertTrue( booleanSelect(dialect.element_in_array( elA, array("'A'", "NULL") )));
assertFalse( booleanSelect(dialect.element_in_array( elA, array("'B'") )));
// this returns NULL, unfortunately using "=" semantics rather than "IS NOT DISTINCT FROM"
assertNull( booleanSelect(dialect.element_in_array( elA, array("'B'", "NULL") )));
assertNull( booleanSelect(dialect.element_in_array( elNull, array("'A'", "'B'") )));
assertNull( booleanSelect(dialect.element_in_array( elNull, array("'A'", "NULL") )));
assertNull( booleanSelect(dialect.element_in_array( elA, elNull)));

assertFalse( booleanSelect(dialect.element_not_in_array( elA, array("'A'", "'B'") )));
assertFalse( booleanSelect(dialect.element_not_in_array( elA, array("'A'", "NULL") )));
assertTrue( booleanSelect(dialect.element_not_in_array( elA, array("'B'") )));
assertNull( booleanSelect(dialect.element_not_in_array( elA, array("'B'", "NULL") )));
assertNull( booleanSelect(dialect.element_not_in_array( elNull, array("'A'", "'B'") )));
assertNull( booleanSelect(dialect.element_not_in_array( elNull, array("'A'", "NULL") )));
assertNull( booleanSelect(dialect.element_not_in_array( elA, elNull)));

assertTrue( booleanSelect(dialect.array_all_in_array( array("'A'"), array("'A'") )));
assertTrue( booleanSelect(dialect.array_all_in_array( array("'A'","'A'"), array("'A'") )));
assertTrue( booleanSelect(dialect.array_all_in_array( array("'A'", "'B'", "'B'"), array("'A'","'B'","'C'") )));
assertFalse( booleanSelect(dialect.array_all_in_array( array("'A'"), array("NULL") )));
assertFalse( booleanSelect(dialect.array_all_in_array( array("NULL"), array("'A'") )));
assertFalse( booleanSelect(dialect.array_all_in_array( array("NULL"), array("NULL") )));
assertNull( booleanSelect(dialect.array_all_in_array( elNull, array("NULL") )));
assertNull( booleanSelect(dialect.array_all_in_array( array("NULL"), elNull )));

assertTrue( booleanSelect(dialect.array_some_in_array( array("'A'", "'B'", "'C'"), array("'A'") )));
assertTrue( booleanSelect(dialect.array_some_in_array( array("'A'"), array("'A'", "'B'", "'C'") )));
assertTrue( booleanSelect(dialect.array_some_in_array( array("'A'","'X'"), array("'A'", "'Y'") )));
assertFalse( booleanSelect(dialect.array_some_in_array( array("'A'","'B'"), array("'X'", "'Y'") )));
assertFalse( booleanSelect(dialect.array_some_in_array( array("'A'"), array("NULL") )));
assertFalse( booleanSelect(dialect.array_some_in_array( array("NULL"), array("'A'") )));
assertFalse( booleanSelect(dialect.array_some_in_array( array("NULL"), array("NULL") )));
assertNull( booleanSelect(dialect.array_some_in_array( elNull, array("NULL") )));
assertNull( booleanSelect(dialect.array_some_in_array( array("NULL"), elNull )));

assertFalse( booleanSelect(dialect.array_none_in_array( array("'A'", "'B'", "'C'"), array("'A'") )));
assertFalse( booleanSelect(dialect.array_none_in_array( array("'A'"), array("'A'", "'B'", "'C'") )));
assertFalse( booleanSelect(dialect.array_none_in_array( array("'A'","'X'"), array("'A'", "'Y'") )));
assertTrue( booleanSelect(dialect.array_none_in_array( array("'A'","'B'"), array("'X'", "'Y'") )));
assertTrue( booleanSelect(dialect.array_none_in_array( array("'A'"), array("NULL") )));
assertTrue( booleanSelect(dialect.array_none_in_array( array("NULL"), array("'A'") )));
assertTrue( booleanSelect(dialect.array_none_in_array( array("NULL"), array("NULL") )));
assertNull( booleanSelect(dialect.array_none_in_array( elNull, array("NULL") )));
assertNull( booleanSelect(dialect.array_none_in_array( array("NULL"), elNull )));
}

@Test
public void testArraySql() throws SQLException
{
if (!dialect.supportsArrays())
return;

var testSql = """
SELECT 'a' as test, false as expected, array_contains_all( ARRAY['A','X'], ARRAY['A','B'] ) as result
UNION ALL
SELECT 'b' as test, true as expected, array_contains_any( ARRAY['A','X'], ARRAY['A','B'] ) as result
UNION ALL
SELECT 'c' as test, false as expected, array_contains_none( ARRAY['A','X'], ARRAY['A','B'] ) as result
UNION ALL
SELECT 'd' as test, false as expected, array_is_same( ARRAY['A','X'], ARRAY['A','B'] ) as result
UNION ALL
SELECT 'e' as test, true as expected, array_is_same( ARRAY['A','B'], ARRAY['A','B'] ) as result
UNION ALL
SELECT 'f' as test, true as expected, array_contains_element( ARRAY['A','B'], 'B') as result
UNION ALL
SELECT 'g' as test, false as expected, array_contains_element( ARRAY['A','B'], 'X') as result
""";

Container container = JunitUtil.getTestContainer();
User user = TestContext.get().getUser();
var schema = DefaultSchema.get(user, container).getSchema("core");
try (var rs =QueryService.get().select(schema, testSql))
{
while (rs.next())
{
var test = rs.getString(1);
var expected = rs.getBoolean(2);
var result = rs.getBoolean(3);
assertEquals("test " + test + " failed", expected, result);
}
}
}
%>
Loading