Skip to content

Commit

Permalink
Merge pull request #3984 from katzyn/invisible
Browse files Browse the repository at this point in the history
Don't include invisible columns into default insert column list
  • Loading branch information
katzyn committed Jan 25, 2024
2 parents cd09d93 + 1b67de8 commit caa35aa
Show file tree
Hide file tree
Showing 9 changed files with 146 additions and 86 deletions.
4 changes: 4 additions & 0 deletions h2/src/docsrc/html/changelog.html
Expand Up @@ -21,6 +21,10 @@ <h1>Change Log</h1>

<h2>Next Version (unreleased)</h2>
<ul>
<li>Issue #3983: INVISIBLE columns should be ignored in INSERT statement without explicit column list
</li>
<li>Issue #3960: NullPointerException when executing batch insert
</li>
<li>Issue #3972: Constraints of local temporary tables aren't listed in INFORMATION_SCHEMA
</li>
<li>PR #3973: Fix Tool.showUsage() for GUIConsole
Expand Down
2 changes: 1 addition & 1 deletion h2/src/main/org/h2/command/dml/Insert.java
Expand Up @@ -286,7 +286,7 @@ void doPrepare() {
// special case where table is used as a sequence
columns = new Column[0];
} else {
columns = table.getColumns();
columns = table.getVisibleColumns();
}
}
if (!valuesExpressionList.isEmpty()) {
Expand Down
2 changes: 1 addition & 1 deletion h2/src/main/org/h2/command/dml/MergeUsing.java
Expand Up @@ -522,7 +522,7 @@ boolean prepare(SessionLocal session) {
TableFilter targetTableFilter = MergeUsing.this.targetTableFilter,
sourceTableFilter = MergeUsing.this.sourceTableFilter;
if (columns == null) {
columns = targetTableFilter.getTable().getColumns();
columns = targetTableFilter.getTable().getVisibleColumns();
}
if (values.length != columns.length) {
throw DbException.get(ErrorCode.COLUMN_COUNT_DOES_NOT_MATCH);
Expand Down
8 changes: 8 additions & 0 deletions h2/src/main/org/h2/res/help.csv
Expand Up @@ -110,6 +110,8 @@ INSERT INTO [schemaName.]tableName [ ( columnName [,...] ) ]
","
Inserts a new row / new rows into a table.

If column names aren't specified a list of all visible columns in the table is assumed.

When using DIRECT, then the results from the query are directly applied in the target table without any intermediate step.
","
INSERT INTO TEST VALUES(1, 'Hello')
Expand Down Expand Up @@ -3550,6 +3552,8 @@ WHEN MATCHED [ AND expression ] THEN
UPDATE SET setClauseList | DELETE
","
WHEN MATCHED clause for MERGE USING command.

Updates or deletes rows in a target table.
","
WHEN MATCHED THEN UPDATE SET NAME = S.NAME
WHEN MATCHED THEN DELETE
Expand All @@ -3562,6 +3566,10 @@ WHEN NOT MATCHED [ AND expression ] THEN INSERT
VALUES ({DEFAULT|expression} [,...])
","
WHEN NOT MATCHED clause for MERGE USING command.

Inserts rows into a target table.

If column names aren't specified a list of all visible columns in the target table is assumed.
","
WHEN NOT MATCHED THEN INSERT (ID, NAME) VALUES (S.ID, S.NAME)
"
Expand Down
36 changes: 35 additions & 1 deletion h2/src/main/org/h2/table/Table.java
Expand Up @@ -721,7 +721,41 @@ public Row getNullRow() {
return row;
}

public Column[] getColumns() {
public final Column[] getColumns() {
return columns;
}

public final Column[] getVisibleColumns() {
Column[] columns = this.columns;
for (int i = 0, count = columns.length; i < count; i++) {
Column column = columns[i];
if (!column.getVisible()) {
return excludeInvisible(columns, count, i);
}
}
return columns;
}

private static Column[] excludeInvisible(Column[] allColumns, int count, int i) {
int invisileCount = 1;
for (int j = i + 1; j < count; j++) {
Column column = allColumns[j];
if (!column.getVisible()) {
invisileCount++;
}
}
Column[] columns = new Column[count - invisileCount];
System.arraycopy(allColumns, 0, columns, 0, i);
if (invisileCount == 1) {
System.arraycopy(allColumns, i + 1, columns, i, count - i - 1);
} else {
for (int j = i + 1; j < count; j++) {
Column column = allColumns[j];
if (column.getVisible()) {
columns[i++] = column;
}
}
}
return columns;
}

Expand Down
2 changes: 1 addition & 1 deletion h2/src/test/org/h2/test/scripts/TestScript.java
Expand Up @@ -222,7 +222,7 @@ public void test() throws Exception {
testScript("functions/window/" + s + ".sql");
}
for (String s : new String[] { "at-time-zone", "boolean-test", "case", "concatenation", "conditions",
"data-change-delta-table", "field-reference", "help", "sequence", "set" }) {
"data-change-delta-table", "field-reference", "help", "invisible", "sequence", "set" }) {
testScript("other/" + s + ".sql");
}
for (String s : new String[] { "comments", "identifiers" }) {
Expand Down
23 changes: 0 additions & 23 deletions h2/src/test/org/h2/test/scripts/ddl/createTable.sql
Expand Up @@ -73,29 +73,6 @@ DROP TABLE T2;
DROP TABLE T1;
> ok

CREATE TABLE TEST(A INT, B INT INVISIBLE);
> ok

SELECT * FROM TEST;
> A
> -
> rows: 0

SELECT A, B FROM TEST;
> A B
> - -
> rows: 0

SELECT COLUMN_NAME, IS_VISIBLE FROM INFORMATION_SCHEMA.COLUMNS WHERE TABLE_NAME = 'TEST' ORDER BY ORDINAL_POSITION;
> COLUMN_NAME IS_VISIBLE
> ----------- ----------
> A TRUE
> B FALSE
> rows (ordered): 2

DROP TABLE TEST;
> ok

CREATE TABLE TEST1(ID IDENTITY);
> ok

Expand Down
96 changes: 96 additions & 0 deletions h2/src/test/org/h2/test/scripts/other/invisible.sql
@@ -0,0 +1,96 @@
-- Copyright 2004-2023 H2 Group. Multiple-Licensed under the MPL 2.0,
-- and the EPL 1.0 (https://h2database.com/html/license.html).
-- Initial Developer: H2 Group
--

create table test(id int, name varchar invisible);
> ok

select * from test;
> ID
> --
> rows: 0

alter table test alter column name set visible;
> ok

select * from test;
> ID NAME
> -- ----
> rows: 0

alter table test add modify_date timestamp invisible before name;
> ok

select * from test;
> ID NAME
> -- ----
> rows: 0

alter table test alter column modify_date timestamp visible;
> ok

select * from test;
> ID MODIFY_DATE NAME
> -- ----------- ----
> rows: 0

alter table test alter column modify_date set invisible;
> ok

select * from test;
> ID NAME
> -- ----
> rows: 0

drop table test;
> ok

CREATE TABLE TEST(A INT, B INT INVISIBLE, C INT);
> ok

INSERT INTO TEST VALUES (1, 2);
> update count: 1

SELECT * FROM TEST;
> A C
> - -
> 1 2
> rows: 1

SELECT A, B, C FROM TEST;
> A B C
> - ---- -
> 1 null 2
> rows: 1

ALTER TABLE TEST ADD D INT INVISIBLE;
> ok

ALTER TABLE TEST ADD E INT;
> ok

MERGE INTO TEST USING (VALUES (4, 5, 6)) T(A, C, E) ON TEST.A = T.A
WHEN NOT MATCHED THEN INSERT VALUES (T.A, T.C, T.E);
> update count: 1

SELECT * FROM TEST;
> A C E
> - - ----
> 1 2 null
> 4 5 6
> rows: 2

SELECT COLUMN_NAME, IS_VISIBLE FROM INFORMATION_SCHEMA.COLUMNS WHERE TABLE_NAME = 'TEST' ORDER BY ORDINAL_POSITION;
> COLUMN_NAME IS_VISIBLE
> ----------- ----------
> A TRUE
> B FALSE
> C TRUE
> D FALSE
> E TRUE
> rows (ordered): 5

DROP TABLE TEST;
> ok

59 changes: 0 additions & 59 deletions h2/src/test/org/h2/test/scripts/testScript.sql
Expand Up @@ -3387,22 +3387,6 @@ SELECT group_concat(name) FROM TEST group by id;
drop table test;
> ok

create table test(a int primary key, b int invisible, c int);
> ok

select * from test;
> A C
> - -
> rows: 0

select a, b, c from test;
> A B C
> - - -
> rows: 0

drop table test;
> ok

--- script drop ---------------------------------------------------------------------------------------------
create memory table test (id int primary key, im_ie varchar(10));
> ok
Expand Down Expand Up @@ -4264,49 +4248,6 @@ SELECT * FROM TEST;
DROP TABLE TEST;
> ok

create table test(id int, name varchar invisible);
> ok

select * from test;
> ID
> --
> rows: 0

alter table test alter column name set visible;
> ok

select * from test;
> ID NAME
> -- ----
> rows: 0

alter table test add modify_date timestamp invisible before name;
> ok

select * from test;
> ID NAME
> -- ----
> rows: 0

alter table test alter column modify_date timestamp visible;
> ok

select * from test;
> ID MODIFY_DATE NAME
> -- ----------- ----
> rows: 0

alter table test alter column modify_date set invisible;
> ok

select * from test;
> ID NAME
> -- ----
> rows: 0

drop table test;
> ok

CREATE MEMORY TABLE TEST(ID INT PRIMARY KEY, NAME VARCHAR);
> ok

Expand Down

0 comments on commit caa35aa

Please sign in to comment.