diff --git a/src/common/backend/nodes/copyfuncs.cpp b/src/common/backend/nodes/copyfuncs.cpp index 1778be377..ed70acb80 100644 --- a/src/common/backend/nodes/copyfuncs.cpp +++ b/src/common/backend/nodes/copyfuncs.cpp @@ -2362,6 +2362,11 @@ static IntoClause* _copyIntoClause(const IntoClause* from) COPY_STRING_FIELD(filename); COPY_SCALAR_FIELD(is_outfile); + if (t_thrd.proc->workingVersionNum >= CREATE_TABLE_AS_VERSION_NUM) { + COPY_NODE_FIELD(tableElts); + COPY_NODE_FIELD(autoIncStart); + COPY_SCALAR_FIELD(onduplicate); + } return newnode; } diff --git a/src/common/backend/nodes/equalfuncs.cpp b/src/common/backend/nodes/equalfuncs.cpp index 9b08dede9..34127f427 100644 --- a/src/common/backend/nodes/equalfuncs.cpp +++ b/src/common/backend/nodes/equalfuncs.cpp @@ -150,6 +150,11 @@ static bool _equalIntoClause(const IntoClause* a, const IntoClause* b) COMPARE_STRING_FIELD(filename); COMPARE_SCALAR_FIELD(is_outfile); + if (t_thrd.proc->workingVersionNum >= CREATE_TABLE_AS_VERSION_NUM) { + COMPARE_NODE_FIELD(tableElts); + COMPARE_NODE_FIELD(autoIncStart); + COMPARE_SCALAR_FIELD(onduplicate); + } return true; } diff --git a/src/common/backend/nodes/outfuncs.cpp b/src/common/backend/nodes/outfuncs.cpp index 381a6434e..cecfddd5d 100755 --- a/src/common/backend/nodes/outfuncs.cpp +++ b/src/common/backend/nodes/outfuncs.cpp @@ -2180,6 +2180,11 @@ static void _outIntoClause(StringInfo str, IntoClause* node) WRITE_STRING_FIELD(filename); WRITE_BOOL_FIELD(is_outfile); } + if (t_thrd.proc->workingVersionNum >= CREATE_TABLE_AS_VERSION_NUM) { + WRITE_NODE_FIELD(tableElts); + WRITE_NODE_FIELD(autoIncStart); + WRITE_ENUM_FIELD(onduplicate, OnDuplicateAction); + } } static void _outVar(StringInfo str, Var* node) diff --git a/src/common/backend/nodes/readfuncs.cpp b/src/common/backend/nodes/readfuncs.cpp index be010670b..f3147fef7 100755 --- a/src/common/backend/nodes/readfuncs.cpp +++ b/src/common/backend/nodes/readfuncs.cpp @@ -1982,6 +1982,15 @@ static IntoClause* _readIntoClause(void) READ_BOOL_FIELD(is_outfile); } + IF_EXIST(tableElts) { + READ_NODE_FIELD(tableElts); + } + IF_EXIST(autoIncStart) { + READ_NODE_FIELD(autoIncStart); + } + IF_EXIST(onduplicate) { + READ_ENUM_FIELD(onduplicate, OnDuplicateAction); + } READ_DONE(); } diff --git a/src/common/backend/parser/analyze.cpp b/src/common/backend/parser/analyze.cpp index eadea9cbc..a1ed3c880 100644 --- a/src/common/backend/parser/analyze.cpp +++ b/src/common/backend/parser/analyze.cpp @@ -2283,7 +2283,8 @@ static void checkUpsertTargetlist(Relation targetTable, List* updateTlist) } } - if (bms_overlap(index_attrs, target_attrs)) { + /* Allow in B_FORMAT */ + if (bms_overlap(index_attrs, target_attrs) && u_sess->attr.attr_sql.sql_compatibility != B_FORMAT) { ereport(ERROR, ((errcode(ERRCODE_FEATURE_NOT_SUPPORTED), errmsg("INSERT ON DUPLICATE KEY UPDATE don't allow update on primary key or unique key.")))); } @@ -4501,6 +4502,38 @@ static Query* transformCreateTableAsStmt(ParseState* pstate, CreateTableAsStmt* /* transform contained query */ stmt->query = (Node*)transformStmt(pstate, stmt->query); + if (u_sess->attr.attr_sql.sql_compatibility == B_FORMAT) { + /* CREATE TABLE AS SELECT is not allowed with Foreign Key and Tablelike Clause*/ + foreach (lc, stmt->into->tableElts) { + Node* node = (Node*)lfirst(lc); + if (IsA(node, ColumnDef)) { + ColumnDef* col = (ColumnDef*) node; + ListCell* cell = NULL; + foreach(cell, col->constraints){ + if (IsA(lfirst(cell), Constraint)) { + Constraint* constraint = (Constraint*) lfirst(cell); + if (constraint->contype == CONSTR_FOREIGN) { + ereport(ERROR, + (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), + errmsg("CREATE TABLE AS SELECT is not allowed with Foreign Key"))); + } + } + } + } else if (IsA(node, Constraint)) { + Constraint* constraint = (Constraint*) node; + if (constraint->contype == CONSTR_FOREIGN) { + ereport(ERROR, + (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), + errmsg("CREATE TABLE AS SELECT is not allowed with Foreign Key"))); + } + } else if (IsA(node, TableLikeClause)) { + ereport(ERROR, + (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), + errmsg("CREATE TABLE AS SELECT is not allowed with Tablelike Clause"))); + } + } + } + /* if result type of new relation is unknown-type, then resolve as type TEXT */ foreach (lc, ((Query*)stmt->query)->targetList) { TargetEntry* tle = (TargetEntry*)lfirst(lc); diff --git a/src/common/backend/parser/gram.y b/src/common/backend/parser/gram.y index 4e7516298..edc507482 100644 --- a/src/common/backend/parser/gram.y +++ b/src/common/backend/parser/gram.y @@ -336,6 +336,7 @@ static void setDelimiterName(core_yyscan_t yyscanner, char*input, VariableSetStm EncryptionType algtype; LockClauseStrength lockstrength; CharsetCollateOptions *charsetcollateopt; + OnDuplicateAction onduplicate; } %type stmt schema_stmt @@ -549,6 +550,7 @@ static void setDelimiterName(core_yyscan_t yyscanner, char*input, VariableSetStm %type opt_trusted opt_restart_seqs opt_purge invoker_rights %type OptTemp OptKind %type OnCommitOption +%type OptDuplicate %type for_locking_strength %type for_locking_item %type for_locking_clause opt_for_locking_clause for_locking_items @@ -873,7 +875,7 @@ static void setDelimiterName(core_yyscan_t yyscanner, char*input, VariableSetStm HANDLER HAVING HDFSDIRECTORY HEADER_P HOLD HOUR_P - IDENTIFIED IDENTITY_P IF_P IGNORE_EXTRA_DATA ILIKE IMMEDIATE IMMUTABLE IMPLICIT_P IN_P INCLUDE + IDENTIFIED IDENTITY_P IF_P IGNORE IGNORE_EXTRA_DATA ILIKE IMMEDIATE IMMUTABLE IMPLICIT_P IN_P INCLUDE INCLUDING INCREMENT INCREMENTAL INDEX INDEXES INFILE INHERIT INHERITS INITIAL_P INITIALLY INITRANS INLINE_P INNER_P INOUT INPUT_P INSENSITIVE INSERT INSTEAD INT_P INTEGER INTERNAL @@ -9150,6 +9152,12 @@ CreateAsStmt: } ; +OptDuplicate: + /* empty */ { $$ = DUPLICATE_ERROR; } + | IGNORE { $$ = DUPLICATE_IGNORE; } + | REPLACE { $$ = DUPLICATE_REPLACE; } + ; + create_as_target: qualified_name opt_column_list OptWith OnCommitOption OptCompress OptTableSpace /* PGXC_BEGIN */ @@ -9170,6 +9178,36 @@ create_as_target: $$->relkind = INTO_CLAUSE_RELKIND_DEFAULT; /* PGXC_END */ } + | qualified_name '(' OptTableElementList ')' OptInherit OptAutoIncrement optCharsetCollate OptWith OnCommitOption OptCompress OptPartitionElement +/* PGXC_BEGIN */ + OptDistributeBy OptSubCluster +/* PGXC_END */ + OptDuplicate + { + if (u_sess->attr.attr_sql.sql_compatibility != B_FORMAT) { + ereport(errstate, (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), + errmsg("define column_definition is supported only in B-format database"))); + } + $$ = makeNode(IntoClause); + $$->rel = $1; + $$->tableElts = $3; + if ($$->tableElts == NIL) { + ereport(ERROR, (errcode(ERRCODE_SYNTAX_ERROR), + errmsg("syntax error at or near \"%s\"", ")"), parser_errposition(@4))); + } + $$->autoIncStart = $6; + $$->options = $8; + $$->onCommit = $9; + $$->row_compress = $10; + $$->tableSpaceName = $11; + $$->skipData = false; /* might get changed later */ +/* PGXC_BEGIN */ + $$->distributeby = $12; + $$->subcluster = $13; + $$->relkind = INTO_CLAUSE_RELKIND_DEFAULT; +/* PGXC_END */ + $$->onduplicate = $14; + } ; opt_with_data: diff --git a/src/common/backend/utils/init/globals.cpp b/src/common/backend/utils/init/globals.cpp index e13c8c9ee..369095557 100644 --- a/src/common/backend/utils/init/globals.cpp +++ b/src/common/backend/utils/init/globals.cpp @@ -179,6 +179,7 @@ const uint32 CREATE_INDEX_IF_NOT_EXISTS_VERSION_NUM = 92843; const uint32 EVENT_VERSION_NUM = 92844; const uint32 SLOW_SQL_VERSION_NUM = 92844; +const uint32 CREATE_TABLE_AS_VERSION_NUM = 92845; #ifdef PGXC bool useLocalXid = false; #endif diff --git a/src/common/interfaces/libpq/frontend_parser/gram.y b/src/common/interfaces/libpq/frontend_parser/gram.y index a444f9fa2..aa4f447e5 100755 --- a/src/common/interfaces/libpq/frontend_parser/gram.y +++ b/src/common/interfaces/libpq/frontend_parser/gram.y @@ -545,7 +545,7 @@ extern THR_LOCAL bool stmt_contains_operator_plus; HANDLER HAVING HDFSDIRECTORY HEADER_P HOLD HOUR_P - IDENTIFIED IDENTITY_P IF_P IGNORE_EXTRA_DATA ILIKE IMMEDIATE IMMUTABLE IMPLICIT_P IN_P + IDENTIFIED IDENTITY_P IF_P IGNORE IGNORE_EXTRA_DATA ILIKE IMMEDIATE IMMUTABLE IMPLICIT_P IN_P INCLUDE INCLUDING INCREMENT INCREMENTAL INDEX INDEXES INFILE INHERIT INHERITS INITIAL_P INITIALLY INITRANS INLINE_P INNER_P INOUT INPUT_P INSENSITIVE INSERT INSTEAD INT_P INTEGER INTERNAL INTERSECT INTERVAL INTO INVISIBLE INVOKER IP IS ISNULL ISOLATION diff --git a/src/gausskernel/optimizer/rewrite/rewriteHandler.cpp b/src/gausskernel/optimizer/rewrite/rewriteHandler.cpp index 795c7155a..6581e5e50 100644 --- a/src/gausskernel/optimizer/rewrite/rewriteHandler.cpp +++ b/src/gausskernel/optimizer/rewrite/rewriteHandler.cpp @@ -87,6 +87,7 @@ static void markQueryForLocking(Query* qry, Node* jtnode, LockClauseStrength str static List* matchLocks(CmdType event, RuleLock* rulelocks, int varno, Query* parsetree); static Query* fireRIRrules(Query* parsetree, List* activeRIRs, bool forUpdatePushedDown); static Bitmapset* adjust_view_column_set(Bitmapset* cols, List* targetlist); +static bool findAttrByName(const char* attributeName, List* tableElts, int maxlen); #ifdef PGXC typedef struct pull_qual_vars_context { @@ -4406,6 +4407,25 @@ char* GetCreateViewStmt(Query* parsetree, CreateTableAsStmt* stmt) return cquery->data; } +static bool findAttrByName(const char* attributeName, List* tableElts, int maxlen) +{ + ListCell* lc = NULL; + int i = 0; + foreach (lc, tableElts) { + if (i >= maxlen) { + return false; + } + Node* node = (Node*)lfirst(lc); + if (IsA(node, ColumnDef)) { + ColumnDef* def = (ColumnDef*)node; + if (pg_strcasecmp(attributeName, def->colname) == 0) + return true; + } + ++i; + } + return false; +} + char* GetCreateTableStmt(Query* parsetree, CreateTableAsStmt* stmt) { /* Start building a CreateStmt for creating the target table */ @@ -4415,6 +4435,10 @@ char* GetCreateTableStmt(Query* parsetree, CreateTableAsStmt* stmt) IntoClause* into = stmt->into; List* tableElts = NIL; + if (u_sess->attr.attr_sql.sql_compatibility == B_FORMAT) + tableElts = stmt->into->tableElts; + int initlen = list_length(tableElts); + /* Obtain the target list of new table */ AssertEreport(IsA(stmt->query, Query), MOD_OPT, ""); Query* cparsetree = (Query*)stmt->query; @@ -4455,6 +4479,10 @@ char* GetCreateTableStmt(Query* parsetree, CreateTableAsStmt* stmt) if (tle->resjunk) continue; + if (u_sess->attr.attr_sql.sql_compatibility == B_FORMAT && findAttrByName(tle->resname, tableElts, initlen)) { + continue; + } + coldef = makeNode(ColumnDef); tpname = makeNode(TypeName); @@ -4528,6 +4556,9 @@ char* GetCreateTableStmt(Query* parsetree, CreateTableAsStmt* stmt) create_stmt->options = stmt->into->options; create_stmt->ivm = stmt->into->ivm; create_stmt->relkind = stmt->relkind == OBJECT_MATVIEW ? RELKIND_MATVIEW : RELKIND_RELATION; + if (u_sess->attr.attr_sql.sql_compatibility == B_FORMAT) { + create_stmt->autoIncStart = stmt->into->autoIncStart; + } /* * Check consistency of arguments */ @@ -4561,7 +4592,8 @@ char* GetCreateTableStmt(Query* parsetree, CreateTableAsStmt* stmt) StringInfo cquery = makeStringInfo(); - deparse_query(parsetree, cquery, NIL, false, false); + if (u_sess->attr.attr_sql.sql_compatibility != B_FORMAT || initlen <= 0) + deparse_query(parsetree, cquery, NIL, false, false); return cquery->data; } @@ -4599,7 +4631,7 @@ static void _copy_top_HintState(HintState *dest, HintState *src) dest->no_expand_hint = src->no_expand_hint; } -char* GetInsertIntoStmt(CreateTableAsStmt* stmt) +char* GetInsertIntoStmt(CreateTableAsStmt* stmt, bool hasNewColumn) { /* Get the SELECT query string */ /* @@ -4642,6 +4674,23 @@ char* GetInsertIntoStmt(CreateTableAsStmt* stmt) else appendStringInfo(cquery, " INTO %s", quote_identifier(relation->relname)); + /* if has new column and have data to insert */ + if (u_sess->attr.attr_sql.sql_compatibility == B_FORMAT && hasNewColumn && !stmt->into->skipData) { + appendStringInfoString(cquery, " ("); + ListCell* lc = NULL; + const char* delimiter = ""; + foreach (lc, select_query->targetList) { + TargetEntry* tle = (TargetEntry*)lfirst(lc); + /* ignore junk column*/ + if (tle->resjunk) + continue; + appendStringInfoString(cquery, delimiter); + delimiter = ", "; + appendStringInfo(cquery, "%s", quote_identifier(tle->resname)); + } + appendStringInfoString(cquery, ")"); + } + /* * If the original sql contains "WITH NO DATA", just create * the table without inserting any data. @@ -4651,6 +4700,33 @@ char* GetInsertIntoStmt(CreateTableAsStmt* stmt) else appendStringInfo(cquery, " %s", selectstr); + /* If there is a new column, there may be a uniqueness conflict */ + if (u_sess->attr.attr_sql.sql_compatibility == B_FORMAT && hasNewColumn && !stmt->into->skipData) { + switch (stmt->into->onduplicate) { + case DUPLICATE_ERROR: + break; + case DUPLICATE_IGNORE: + appendStringInfoString(cquery, " ON DUPLICATE KEY UPDATE NOTHING"); + break; + case DUPLICATE_REPLACE: { + appendStringInfoString(cquery, " ON DUPLICATE KEY UPDATE "); + ListCell* lc = NULL; + const char* delimiter = ""; + foreach (lc, select_query->targetList) { + TargetEntry* tle = (TargetEntry*)lfirst(lc); + /* ignore junk column*/ + if (tle->resjunk) + continue; + appendStringInfoString(cquery, delimiter); + delimiter = ", "; + appendStringInfo(cquery, "%s = VALUES(%s)", quote_identifier(tle->resname), quote_identifier(tle->resname)); + } + break; + } + default: + break; + } + } return cquery->data; } @@ -4886,7 +4962,10 @@ List* QueryRewriteCTAS(Query* parsetree) /* CREATE TABLE AS */ Query* cparsetree = (Query*)copyObject(parsetree); + bool hasNewColumn = stmt->into->tableElts != NULL; char* create_sql = GetCreateTableStmt(cparsetree, stmt); + /* move stmt->into->tableElts to create_stmt->tableElts */ + stmt->into->tableElts = NULL; if (stmt->relkind == OBJECT_MATVIEW) { zparsetree = (Query*)copyObject(cparsetree); @@ -4938,7 +5017,7 @@ List* QueryRewriteCTAS(Query* parsetree) */ parsetree->utilityStmt = NULL; - char* insert_into_sqlstr = GetInsertIntoStmt(stmt); + char* insert_into_sqlstr = GetInsertIntoStmt(stmt, hasNewColumn); raw_parsetree_list = pg_parse_query(insert_into_sqlstr); diff --git a/src/include/miscadmin.h b/src/include/miscadmin.h index 53d09e6d2..116c954d7 100644 --- a/src/include/miscadmin.h +++ b/src/include/miscadmin.h @@ -127,6 +127,7 @@ extern const uint32 INSERT_RIGHT_REF_VERSION_NUM; extern const uint32 CREATE_INDEX_IF_NOT_EXISTS_VERSION_NUM; extern const uint32 SLOW_SQL_VERSION_NUM; extern const uint32 INDEX_HINT_VERSION_NUM; +extern const uint32 CREATE_TABLE_AS_VERSION_NUM; extern void register_backend_version(uint32 backend_version); extern bool contain_backend_version(uint32 version_number); diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h index 9efd0343f..2daaa373a 100644 --- a/src/include/nodes/primnodes.h +++ b/src/include/nodes/primnodes.h @@ -68,6 +68,13 @@ typedef enum OptCompress { COMPRESS_HIGH, } OptCompress; +/* How to handle rows that duplicate unique key values */ +typedef enum OnDuplicateAction { + DUPLICATE_ERROR = 0, + DUPLICATE_IGNORE, + DUPLICATE_REPLACE +} OnDuplicate; + /* * RangeVar - range variable, used in FROM clauses * @@ -126,6 +133,9 @@ typedef struct IntoClause { struct DistributeBy* distributeby; /* distribution to use, or NULL */ struct PGXCSubCluster* subcluster; /* subcluster node members */ #endif + List* tableElts; /* column definitions(list of ColumnDef) */ + Node *autoIncStart; /* DefElem for AUTO_INCREMENT = value*/ + OnDuplicateAction onduplicate; /* how to handle rows that duplicate unique key values */ } IntoClause; /* ---------------------------------------------------------------- diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h index 448b95814..503a42912 100644 --- a/src/include/parser/kwlist.h +++ b/src/include/parser/kwlist.h @@ -289,6 +289,7 @@ PG_KEYWORD("hour", HOUR_P, UNRESERVED_KEYWORD) PG_KEYWORD("identified", IDENTIFIED, UNRESERVED_KEYWORD) PG_KEYWORD("identity", IDENTITY_P, UNRESERVED_KEYWORD) PG_KEYWORD("if", IF_P, UNRESERVED_KEYWORD) +PG_KEYWORD("ignore", IGNORE, UNRESERVED_KEYWORD) PG_KEYWORD("ignore_extra_data", IGNORE_EXTRA_DATA, UNRESERVED_KEYWORD) PG_KEYWORD("ilike", ILIKE, TYPE_FUNC_NAME_KEYWORD) PG_KEYWORD("immediate", IMMEDIATE, UNRESERVED_KEYWORD) diff --git a/src/test/regress/expected/create_table.out b/src/test/regress/expected/create_table.out index 79494b281..dc1e26a20 100644 --- a/src/test/regress/expected/create_table.out +++ b/src/test/regress/expected/create_table.out @@ -2191,3 +2191,220 @@ Options: orientation=row, compression=no drop table test_primary; \c postgres +-- test mysql "create table as" +-- a format +create database a_createas dbcompatibility 'A'; +\c a_createas +create table t_base(col1 int, col2 int, col3 int); +create table t1 as select * from t_base; +select * from t1; + col1 | col2 | col3 +------+------+------ +(0 rows) + +create table t2(col) as select * from t_base; +select * from t2; + col | col2 | col3 +-----+------+------ +(0 rows) + +-- fail +create table t3(col1,col2,col3,col4) as select * from t_base; +ERROR: CREATE TABLE AS specifies too many column names +create table t4(col int) as select * from t_base; +ERROR: define column_definition is supported only in B-format database +-- b format +create database b_createas dbcompatibility 'B'; +\c b_createas +create table t_base(col1 int, col2 int, col3 int); +create table t1 as select * from t_base; +select * from t1; + col1 | col2 | col3 +------+------+------ +(0 rows) + +create table t2(col) as select * from t_base; +select * from t2; + col | col2 | col3 +-----+------+------ +(0 rows) + +create table t3(col int) as select * from t_base; +select * from t3; + col | col1 | col2 | col3 +-----+------+------+------ +(0 rows) + +create table t4(col1 int) as select * from t_base; +select * from t4; + col1 | col2 | col3 +------+------+------ +(0 rows) + +-- fail +create table t5() as select * from t_base; +ERROR: syntax error at or near ")" +LINE 1: create table t5() as select * from t_base; + ^ +create table t6(col1 int) as select col1,* from t_base; +ERROR: column "col1" specified more than once +LINE 1: create table t6(col1 int) as select col1,* from t_base; + ^ +-- duplicate key +insert into t_base values(1,1,10),(1,2,9),(2,2,8),(2,1,7),(1,1,6); +-- error +create table t7(col1 int unique) as select * from t_base; +NOTICE: CREATE TABLE / UNIQUE will create implicit index "t7_col1_key" for table "t7" +ERROR: duplicate key value violates unique constraint "t7_col1_key" +DETAIL: Key (col1)=(1) already exists. +-- ignore +create table t8(col1 int unique) ignore as select * from t_base; +NOTICE: CREATE TABLE / UNIQUE will create implicit index "t8_col1_key" for table "t8" +select * from t8; + col1 | col2 | col3 +------+------+------ + 1 | 1 | 10 + 2 | 2 | 8 +(2 rows) + +-- replace +create table t9(col1 int unique) replace as select * from t_base; +NOTICE: CREATE TABLE / UNIQUE will create implicit index "t9_col1_key" for table "t9" +select * from t9 order by col3; + col1 | col2 | col3 +------+------+------ + 1 | 1 | 6 + 2 | 1 | 7 +(2 rows) + +create table t10(col1 int unique, col2 int unique) replace as select * from t_base; +NOTICE: CREATE TABLE / UNIQUE will create implicit index "t10_col1_key" for table "t10" +NOTICE: CREATE TABLE / UNIQUE will create implicit index "t10_col2_key" for table "t10" +select * from t10 order by col3; + col1 | col2 | col3 +------+------+------ + 1 | 1 | 6 +(1 row) + +-- foreign key +create table ftable(col int primary key); +NOTICE: CREATE TABLE / PRIMARY KEY will create implicit index "ftable_pkey" for table "ftable" +create table t11(col int, foreign key(col) references ftable(col)) as select * from t_base; +ERROR: CREATE TABLE AS SELECT is not allowed with Foreign Key +create table t12(col int references ftable(col)) as select * from t_base; +ERROR: CREATE TABLE AS SELECT is not allowed with Foreign Key +create table t13(foreign key(col1) references ftable(col)) as select * from t_base; +ERROR: CREATE TABLE AS SELECT is not allowed with Foreign Key +-- table like +create table t14(like t_base) as select * from t_base; +ERROR: CREATE TABLE AS SELECT is not allowed with Tablelike Clause +-- with no data +create table t15(id int, name char(8)); +insert into t15(id) select generate_series(1,10); +create table t16(col1 int, id int) as select * from t15 where id with no data; +select * from t16; + col1 | id | name +------+----+------ +(0 rows) + +create table t17(col1 int, id int unique) replace as select * from t15 where id with no data; +NOTICE: CREATE TABLE / UNIQUE will create implicit index "t17_id_key" for table "t17" +select * from t17; + col1 | id | name +------+----+------ +(0 rows) + +-- union all +create table test1(id int,name varchar(10),score numeric,date1 date,c1 bytea); +insert into test1 values(1,'aaa',97.1,'1999-12-12','0101'); +insert into test1 values(5,'bbb',36.9,'1998-01-12','0110'); +insert into test1 values(30,'ooo',90.1,'2023-01-30','1001'); +insert into test1 values(6,'hhh',60,'2022-12-22','1010'); +insert into test1 values(7,'fff',71,'2001-11-23','1011'); +insert into test1 values(-1,'yaya',77.7,'2008-09-10','1100'); +insert into test1 values(7,'fff',71,'2001-11-23','1011'); +insert into test1 values(null,null,null,null,null); +create table test2(id int,name varchar(10),score numeric,date1 date,c1 bytea); +insert into test2 values(1,'aaa',99.1,'1998-12-12','0101'); +insert into test2 values(2,'hhh',36.9,'1996-01-12','0110'); +insert into test2 values(3,'ddd',89.2,'2000-03-12','0111'); +insert into test2 values(7,'uuu',60.9,'1997-01-01','1000'); +insert into test2 values(11,'eee',71,'2011-11-20','1011'); +insert into test2 values(-1,'yaya',76.7,'2008-09-10','1100'); +insert into test2 values(7,'uuu',60.9,'1997-01-01','1000'); +insert into test2 values(null,null,null,null,null); +create table tb1(col1 int,id int) as select * from test1 where id<4 union all select * from test2 where score>80 order by id,score; +select * from tb1 order by id; + col1 | id | name | score | date1 | c1 +------+----+------+-------+------------+------------ + | -1 | yaya | 77.7 | 09-10-2008 | \x31313030 + | 1 | aaa | 97.1 | 12-12-1999 | \x30313031 + | 1 | aaa | 99.1 | 12-12-1998 | \x30313031 + | 3 | ddd | 89.2 | 03-12-2000 | \x30313131 +(4 rows) + +create table tb2(col1 int,id int unique) replace as select * from test1 where id<4 union all select * from test2 where score>80 order by id,score; +NOTICE: CREATE TABLE / UNIQUE will create implicit index "tb2_id_key" for table "tb2" +select * from tb2 order by id; + col1 | id | name | score | date1 | c1 +------+----+------+-------+------------+------------ + | -1 | yaya | 77.7 | 09-10-2008 | \x31313030 + | 1 | aaa | 99.1 | 12-12-1998 | \x30313031 + | 3 | ddd | 89.2 | 03-12-2000 | \x30313131 +(3 rows) + +-- test update +create table tb_primary(a int primary key, b int); +NOTICE: CREATE TABLE / PRIMARY KEY will create implicit index "tb_primary_pkey" for table "tb_primary" +create table tb_unique(a int unique, b int); +NOTICE: CREATE TABLE / UNIQUE will create implicit index "tb_unique_a_key" for table "tb_unique" +insert into tb_primary values(1,2),(2,4),(3,6); +insert into tb_unique values(1,2),(2,4),(3,6); +-- error +insert into tb_primary values(1,1); +ERROR: duplicate key value violates unique constraint "tb_primary_pkey" +DETAIL: Key (a)=(1) already exists. +insert into tb_unique values(1,1); +ERROR: duplicate key value violates unique constraint "tb_unique_a_key" +DETAIL: Key (a)=(1) already exists. +-- UPDATE nothing +insert into tb_primary values(1,1) ON DUPLICATE KEY UPDATE NOTHING; +insert into tb_unique values(1,1) ON DUPLICATE KEY UPDATE NOTHING; +select * from tb_primary; + a | b +---+--- + 1 | 2 + 2 | 4 + 3 | 6 +(3 rows) + +select * from tb_unique; + a | b +---+--- + 1 | 2 + 2 | 4 + 3 | 6 +(3 rows) + +-- UPDATE +insert into tb_primary values(1,1) ON DUPLICATE KEY UPDATE a = 1, b = 1; +insert into tb_unique values(1,1) ON DUPLICATE KEY UPDATE a = 1, b = 1; +select * from tb_primary; + a | b +---+--- + 2 | 4 + 3 | 6 + 1 | 1 +(3 rows) + +select * from tb_unique; + a | b +---+--- + 2 | 4 + 3 | 6 + 1 | 1 +(3 rows) + +\c postgres +drop database a_createas; +drop database b_createas; diff --git a/src/test/regress/sql/create_table.sql b/src/test/regress/sql/create_table.sql index f3664446f..da650850d 100644 --- a/src/test/regress/sql/create_table.sql +++ b/src/test/regress/sql/create_table.sql @@ -1471,3 +1471,112 @@ create table test_primary(f11 int, f12 varchar(20), f13 bool, constraint con_t_p drop table test_primary; \c postgres +-- test mysql "create table as" +-- a format +create database a_createas dbcompatibility 'A'; +\c a_createas + +create table t_base(col1 int, col2 int, col3 int); + +create table t1 as select * from t_base; +select * from t1; +create table t2(col) as select * from t_base; +select * from t2; +-- fail +create table t3(col1,col2,col3,col4) as select * from t_base; +create table t4(col int) as select * from t_base; + +-- b format +create database b_createas dbcompatibility 'B'; +\c b_createas + +create table t_base(col1 int, col2 int, col3 int); + +create table t1 as select * from t_base; +select * from t1; +create table t2(col) as select * from t_base; +select * from t2; +create table t3(col int) as select * from t_base; +select * from t3; +create table t4(col1 int) as select * from t_base; +select * from t4; + +-- fail +create table t5() as select * from t_base; +create table t6(col1 int) as select col1,* from t_base; + +-- duplicate key +insert into t_base values(1,1,10),(1,2,9),(2,2,8),(2,1,7),(1,1,6); +-- error +create table t7(col1 int unique) as select * from t_base; +-- ignore +create table t8(col1 int unique) ignore as select * from t_base; +select * from t8; +-- replace +create table t9(col1 int unique) replace as select * from t_base; +select * from t9 order by col3; +create table t10(col1 int unique, col2 int unique) replace as select * from t_base; +select * from t10 order by col3; + +-- foreign key +create table ftable(col int primary key); +create table t11(col int, foreign key(col) references ftable(col)) as select * from t_base; +create table t12(col int references ftable(col)) as select * from t_base; +create table t13(foreign key(col1) references ftable(col)) as select * from t_base; +-- table like +create table t14(like t_base) as select * from t_base; + +-- with no data +create table t15(id int, name char(8)); +insert into t15(id) select generate_series(1,10); +create table t16(col1 int, id int) as select * from t15 where id with no data; +select * from t16; +create table t17(col1 int, id int unique) replace as select * from t15 where id with no data; +select * from t17; + +-- union all +create table test1(id int,name varchar(10),score numeric,date1 date,c1 bytea); +insert into test1 values(1,'aaa',97.1,'1999-12-12','0101'); +insert into test1 values(5,'bbb',36.9,'1998-01-12','0110'); +insert into test1 values(30,'ooo',90.1,'2023-01-30','1001'); +insert into test1 values(6,'hhh',60,'2022-12-22','1010'); +insert into test1 values(7,'fff',71,'2001-11-23','1011'); +insert into test1 values(-1,'yaya',77.7,'2008-09-10','1100'); +insert into test1 values(7,'fff',71,'2001-11-23','1011'); +insert into test1 values(null,null,null,null,null); +create table test2(id int,name varchar(10),score numeric,date1 date,c1 bytea); +insert into test2 values(1,'aaa',99.1,'1998-12-12','0101'); +insert into test2 values(2,'hhh',36.9,'1996-01-12','0110'); +insert into test2 values(3,'ddd',89.2,'2000-03-12','0111'); +insert into test2 values(7,'uuu',60.9,'1997-01-01','1000'); +insert into test2 values(11,'eee',71,'2011-11-20','1011'); +insert into test2 values(-1,'yaya',76.7,'2008-09-10','1100'); +insert into test2 values(7,'uuu',60.9,'1997-01-01','1000'); +insert into test2 values(null,null,null,null,null); +create table tb1(col1 int,id int) as select * from test1 where id<4 union all select * from test2 where score>80 order by id,score; +select * from tb1 order by id; +create table tb2(col1 int,id int unique) replace as select * from test1 where id<4 union all select * from test2 where score>80 order by id,score; +select * from tb2 order by id; + +-- test update +create table tb_primary(a int primary key, b int); +create table tb_unique(a int unique, b int); +insert into tb_primary values(1,2),(2,4),(3,6); +insert into tb_unique values(1,2),(2,4),(3,6); +-- error +insert into tb_primary values(1,1); +insert into tb_unique values(1,1); +-- UPDATE nothing +insert into tb_primary values(1,1) ON DUPLICATE KEY UPDATE NOTHING; +insert into tb_unique values(1,1) ON DUPLICATE KEY UPDATE NOTHING; +select * from tb_primary; +select * from tb_unique; +-- UPDATE +insert into tb_primary values(1,1) ON DUPLICATE KEY UPDATE a = 1, b = 1; +insert into tb_unique values(1,1) ON DUPLICATE KEY UPDATE a = 1, b = 1; +select * from tb_primary; +select * from tb_unique; + +\c postgres +drop database a_createas; +drop database b_createas;