Skip to content
Projects
Groups
Snippets
Help
Loading...
Help
Support
Keyboard shortcuts
?
Submit feedback
Contribute to GitLab
Sign in
Toggle navigation
P
Postgres FD Implementation
Project overview
Project overview
Details
Activity
Releases
Repository
Repository
Files
Commits
Branches
Tags
Contributors
Graph
Compare
Issues
0
Issues
0
List
Boards
Labels
Milestones
Merge Requests
0
Merge Requests
0
CI / CD
CI / CD
Pipelines
Jobs
Schedules
Analytics
Analytics
CI / CD
Repository
Value Stream
Wiki
Wiki
Snippets
Snippets
Members
Members
Collapse sidebar
Close sidebar
Activity
Graph
Create a new issue
Jobs
Commits
Issue Boards
Open sidebar
Abuhujair Javed
Postgres FD Implementation
Commits
85188ab8
Commit
85188ab8
authored
Aug 30, 2006
by
Tom Lane
Browse files
Options
Browse Files
Download
Email Patches
Plain Diff
Extend COPY to support COPY (SELECT ...) TO ...
Bernd Helmle
parent
0d506578
Changes
16
Expand all
Show whitespace changes
Inline
Side-by-side
Showing
16 changed files
with
843 additions
and
328 deletions
+843
-328
doc/src/sgml/ref/copy.sgml
doc/src/sgml/ref/copy.sgml
+24
-16
doc/src/sgml/ref/psql-ref.sgml
doc/src/sgml/ref/psql-ref.sgml
+3
-6
src/backend/commands/copy.c
src/backend/commands/copy.c
+519
-290
src/backend/nodes/copyfuncs.c
src/backend/nodes/copyfuncs.c
+2
-1
src/backend/nodes/equalfuncs.c
src/backend/nodes/equalfuncs.c
+2
-1
src/backend/parser/analyze.c
src/backend/parser/analyze.c
+14
-1
src/backend/parser/gram.y
src/backend/parser/gram.y
+20
-3
src/backend/tcop/dest.c
src/backend/tcop/dest.c
+8
-1
src/bin/psql/copy.c
src/bin/psql/copy.c
+24
-1
src/include/commands/copy.h
src/include/commands/copy.h
+4
-1
src/include/nodes/parsenodes.h
src/include/nodes/parsenodes.h
+8
-2
src/include/tcop/dest.h
src/include/tcop/dest.h
+3
-2
src/test/regress/expected/copyselect.out
src/test/regress/expected/copyselect.out
+126
-0
src/test/regress/parallel_schedule
src/test/regress/parallel_schedule
+2
-2
src/test/regress/serial_schedule
src/test/regress/serial_schedule
+2
-1
src/test/regress/sql/copyselect.sql
src/test/regress/sql/copyselect.sql
+82
-0
No files found.
doc/src/sgml/ref/copy.sgml
View file @
85188ab8
<!--
$PostgreSQL: pgsql/doc/src/sgml/ref/copy.sgml,v 1.7
4 2006/04/22 03:03:11 momjian
Exp $
$PostgreSQL: pgsql/doc/src/sgml/ref/copy.sgml,v 1.7
5 2006/08/30 23:34:20 tgl
Exp $
PostgreSQL documentation
-->
...
...
@@ -33,7 +33,7 @@ COPY <replaceable class="parameter">tablename</replaceable> [ ( <replaceable cla
[ ESCAPE [ AS ] '<replaceable class="parameter">escape</replaceable>' ]
[ FORCE NOT NULL <replaceable class="parameter">column</replaceable> [, ...] ]
COPY
<replaceable class="parameter">tablename</replaceable> [ ( <replaceable class="parameter">column</replaceable> [, ...] ) ]
COPY
{ <replaceable class="parameter">tablename</replaceable> [ ( <replaceable class="parameter">column</replaceable> [, ...] ) ] | ( <replaceable class="parameter">query</replaceable> ) }
TO { '<replaceable class="parameter">filename</replaceable>' | STDOUT }
[ [ WITH ]
[ BINARY ]
...
...
@@ -57,7 +57,8 @@ COPY <replaceable class="parameter">tablename</replaceable> [ ( <replaceable cla
files. <command>COPY TO</command> copies the contents of a table
<emphasis>to</> a file, while <command>COPY FROM</command> copies
data <emphasis>from</> a file to a table (appending the data to
whatever is in the table already).
whatever is in the table already). <command>COPY TO</command>
can also copy the results of a <command>SELECT</> query.
</para>
<para>
...
...
@@ -97,7 +98,17 @@ COPY <replaceable class="parameter">tablename</replaceable> [ ( <replaceable cla
<listitem>
<para>
An optional list of columns to be copied. If no column list is
specified, all columns will be used.
specified, all columns of the table will be copied.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="parameter">query</replaceable></term>
<listitem>
<para>
A <command>SELECT</> query whose results are to be copied.
Note that parentheses are required around the query.
</para>
</listitem>
</varlistentry>
...
...
@@ -148,7 +159,8 @@ COPY <replaceable class="parameter">tablename</replaceable> [ ( <replaceable cla
<para>
Specifies copying the OID for each row. (An error is raised if
<literal>OIDS</literal> is specified for a table that does not
have OIDs.)
have OIDs, or in the case of copying a <replaceable
class="parameter">query</replaceable>.)
</para>
</listitem>
</varlistentry>
...
...
@@ -265,7 +277,7 @@ COPY <replaceable class="parameter">tablename</replaceable> [ ( <replaceable cla
COPY <replaceable class="parameter">count</replaceable>
</screen>
The <replaceable class="parameter">count</replaceable> is the number
of rows
inserted into or copied from the table
.
of rows
copied
.
</para>
</refsect1>
...
...
@@ -274,7 +286,8 @@ COPY <replaceable class="parameter">count</replaceable>
<para>
<command>COPY</command> can only be used with plain tables, not
with views.
with views. However, you can write <literal>COPY (SELECT * FROM
<replaceable class="parameter">viewname</replaceable>) TO ...</literal>.
</para>
<para>
...
...
@@ -320,8 +333,8 @@ COPY <replaceable class="parameter">count</replaceable>
server in the case of <command>COPY TO</command>, but for
<command>COPY FROM</command> you do have the option of reading from
a file specified by a relative path. The path will be interpreted
relative to the working directory of the server process (
somewhere below
the data directory), not the client's working directory.
relative to the working directory of the server process (
normally
the
cluster's
data directory), not the client's working directory.
</para>
<para>
...
...
@@ -737,14 +750,9 @@ COPY country FROM '/usr1/proj/bray/sql/country_data';
</para>
<para>
To copy into a file just the countries whose names start with 'A'
using a temporary table which is automatically deleted:
To copy into a file just the countries whose names start with 'A':
<programlisting>
BEGIN;
CREATE TEMP TABLE a_list_countries AS
SELECT * FROM country WHERE country_name LIKE 'A%';
COPY a_list_countries TO '/usr1/proj/bray/sql/a_list_countries.copy';
ROLLBACK;
COPY (SELECT * FROM country WHERE country_name LIKE 'A%') TO '/usr1/proj/bray/sql/a_list_countries.copy';
</programlisting>
</para>
...
...
doc/src/sgml/ref/psql-ref.sgml
View file @
85188ab8
<!--
$PostgreSQL: pgsql/doc/src/sgml/ref/psql-ref.sgml,v 1.16
7 2006/08/29 22:25:04
tgl Exp $
$PostgreSQL: pgsql/doc/src/sgml/ref/psql-ref.sgml,v 1.16
8 2006/08/30 23:34:21
tgl Exp $
PostgreSQL documentation
-->
...
...
@@ -739,8 +739,7 @@ testdb=>
</varlistentry>
<varlistentry>
<term><literal>\copy <replaceable class="parameter">table</replaceable>
[ ( <replaceable class="parameter">column_list</replaceable> ) ]
<term><literal>\copy { <replaceable class="parameter">table</replaceable> [ ( <replaceable class="parameter">column_list</replaceable> ) ] | ( <replaceable class="parameter">query</replaceable> ) }
{ <literal>from</literal> | <literal>to</literal> }
{ <replaceable class="parameter">filename</replaceable> | stdin | stdout | pstdin | pstdout }
[ with ]
...
...
@@ -779,9 +778,7 @@ testdb=>
</para>
<para>
<literal>\copy <replaceable
class="parameter">table</replaceable> from <replaceable
class="parameter">stdin | stdout</replaceable></literal>
<literal>\copy ... from stdin | to stdout</literal>
reads/writes based on the command input and output respectively.
All rows are read from the same source that issued the command,
continuing until <literal>\.</literal> is read or the stream
...
...
src/backend/commands/copy.c
View file @
85188ab8
This diff is collapsed.
Click to expand it.
src/backend/nodes/copyfuncs.c
View file @
85188ab8
...
...
@@ -15,7 +15,7 @@
* Portions Copyright (c) 1994, Regents of the University of California
*
* IDENTIFICATION
* $PostgreSQL: pgsql/src/backend/nodes/copyfuncs.c,v 1.3
49 2006/08/25 04:06:49
tgl Exp $
* $PostgreSQL: pgsql/src/backend/nodes/copyfuncs.c,v 1.3
50 2006/08/30 23:34:21
tgl Exp $
*
*-------------------------------------------------------------------------
*/
...
...
@@ -1934,6 +1934,7 @@ _copyCopyStmt(CopyStmt *from)
CopyStmt
*
newnode
=
makeNode
(
CopyStmt
);
COPY_NODE_FIELD
(
relation
);
COPY_NODE_FIELD
(
query
);
COPY_NODE_FIELD
(
attlist
);
COPY_SCALAR_FIELD
(
is_from
);
COPY_STRING_FIELD
(
filename
);
...
...
src/backend/nodes/equalfuncs.c
View file @
85188ab8
...
...
@@ -18,7 +18,7 @@
* Portions Copyright (c) 1994, Regents of the University of California
*
* IDENTIFICATION
* $PostgreSQL: pgsql/src/backend/nodes/equalfuncs.c,v 1.28
3 2006/08/25 04:06:49
tgl Exp $
* $PostgreSQL: pgsql/src/backend/nodes/equalfuncs.c,v 1.28
4 2006/08/30 23:34:21
tgl Exp $
*
*-------------------------------------------------------------------------
*/
...
...
@@ -863,6 +863,7 @@ static bool
_equalCopyStmt
(
CopyStmt
*
a
,
CopyStmt
*
b
)
{
COMPARE_NODE_FIELD
(
relation
);
COMPARE_NODE_FIELD
(
query
);
COMPARE_NODE_FIELD
(
attlist
);
COMPARE_SCALAR_FIELD
(
is_from
);
COMPARE_STRING_FIELD
(
filename
);
...
...
src/backend/parser/analyze.c
View file @
85188ab8
...
...
@@ -6,7 +6,7 @@
* Portions Copyright (c) 1996-2006, PostgreSQL Global Development Group
* Portions Copyright (c) 1994, Regents of the University of California
*
* $PostgreSQL: pgsql/src/backend/parser/analyze.c,v 1.34
8 2006/08/25 04:06:5
1 tgl Exp $
* $PostgreSQL: pgsql/src/backend/parser/analyze.c,v 1.34
9 2006/08/30 23:34:2
1 tgl Exp $
*
*-------------------------------------------------------------------------
*/
...
...
@@ -341,6 +341,19 @@ transformStmt(ParseState *pstate, Node *parseTree,
}
break
;
case
T_CopyStmt
:
{
CopyStmt
*
n
=
(
CopyStmt
*
)
parseTree
;
result
=
makeNode
(
Query
);
result
->
commandType
=
CMD_UTILITY
;
if
(
n
->
query
)
n
->
query
=
transformStmt
(
pstate
,
(
Node
*
)
n
->
query
,
extras_before
,
extras_after
);
result
->
utilityStmt
=
(
Node
*
)
parseTree
;
}
break
;
case
T_AlterTableStmt
:
result
=
transformAlterTableStmt
(
pstate
,
(
AlterTableStmt
*
)
parseTree
,
...
...
src/backend/parser/gram.y
View file @
85188ab8
...
...
@@ -11,7 +11,7 @@
*
*
* IDENTIFICATION
* $PostgreSQL: pgsql/src/backend/parser/gram.y,v 2.55
8 2006/08/25 04:06:5
1 tgl Exp $
* $PostgreSQL: pgsql/src/backend/parser/gram.y,v 2.55
9 2006/08/30 23:34:2
1 tgl Exp $
*
* HISTORY
* AUTHOR DATE MAJOR EVENT
...
...
@@ -1614,11 +1614,15 @@ ClosePortalStmt:
/*****************************************************************************
*
* QUERY :
* COPY
<relname> ['(' columnList ')'] FROM/TO
[WITH options]
* COPY
relname ['(' columnList ')'] FROM/TO file
[WITH options]
*
* BINARY, OIDS, and DELIMITERS kept in old locations
* for backward compatibility. 2002-06-18
*
* COPY ( SELECT ... ) TO file [WITH options]
* This form doesn't have the backwards-compatible option
* syntax.
*
*****************************************************************************/
CopyStmt: COPY opt_binary qualified_name opt_column_list opt_oids
...
...
@@ -1626,6 +1630,7 @@ CopyStmt: COPY opt_binary qualified_name opt_column_list opt_oids
{
CopyStmt *n = makeNode(CopyStmt);
n->relation = $3;
n->query = NULL;
n->attlist = $4;
n->is_from = $6;
n->filename = $7;
...
...
@@ -1642,6 +1647,18 @@ CopyStmt: COPY opt_binary qualified_name opt_column_list opt_oids
n->options = list_concat(n->options, $10);
$$ = (Node *)n;
}
| COPY select_with_parens TO copy_file_name opt_with
copy_opt_list
{
CopyStmt *n = makeNode(CopyStmt);
n->relation = NULL;
n->query = (Query *) $2;
n->attlist = NIL;
n->is_from = false;
n->filename = $4;
n->options = $6;
$$ = (Node *)n;
}
;
copy_from:
...
...
@@ -1652,7 +1669,7 @@ copy_from:
/*
* copy_file_name NULL indicates stdio is used. Whether stdin or stdout is
* used depends on the direction. (It really doesn't make sense to copy from
* stdout. We silently correct the "typo". - AY 9/94
* stdout. We silently correct the "typo".
)
- AY 9/94
*/
copy_file_name:
Sconst { $$ = $1; }
...
...
src/backend/tcop/dest.c
View file @
85188ab8
...
...
@@ -8,7 +8,7 @@
* Portions Copyright (c) 1994, Regents of the University of California
*
* IDENTIFICATION
* $PostgreSQL: pgsql/src/backend/tcop/dest.c,v 1.
69 2006/08/12 02:52:05
tgl Exp $
* $PostgreSQL: pgsql/src/backend/tcop/dest.c,v 1.
70 2006/08/30 23:34:21
tgl Exp $
*
*-------------------------------------------------------------------------
*/
...
...
@@ -30,6 +30,7 @@
#include "access/printtup.h"
#include "access/xact.h"
#include "commands/copy.h"
#include "executor/executor.h"
#include "executor/tstoreReceiver.h"
#include "libpq/libpq.h"
...
...
@@ -128,6 +129,9 @@ CreateDestReceiver(CommandDest dest, Portal portal)
case
DestIntoRel
:
return
CreateIntoRelDestReceiver
();
case
DestCopyOut
:
return
CreateCopyDestReceiver
();
}
/* should never get here */
...
...
@@ -153,6 +157,7 @@ EndCommand(const char *commandTag, CommandDest dest)
case
DestSPI
:
case
DestTuplestore
:
case
DestIntoRel
:
case
DestCopyOut
:
break
;
}
}
...
...
@@ -192,6 +197,7 @@ NullCommand(CommandDest dest)
case
DestSPI
:
case
DestTuplestore
:
case
DestIntoRel
:
case
DestCopyOut
:
break
;
}
}
...
...
@@ -233,6 +239,7 @@ ReadyForQuery(CommandDest dest)
case
DestSPI
:
case
DestTuplestore
:
case
DestIntoRel
:
case
DestCopyOut
:
break
;
}
}
src/bin/psql/copy.c
View file @
85188ab8
...
...
@@ -3,7 +3,7 @@
*
* Copyright (c) 2000-2006, PostgreSQL Global Development Group
*
* $PostgreSQL: pgsql/src/bin/psql/copy.c,v 1.6
7 2006/08/29 15:19:50
tgl Exp $
* $PostgreSQL: pgsql/src/bin/psql/copy.c,v 1.6
8 2006/08/30 23:34:22
tgl Exp $
*/
#include "postgres_fe.h"
#include "copy.h"
...
...
@@ -39,6 +39,9 @@
* \copy tablename [(columnlist)] from|to filename
* [ with ] [ binary ] [ oids ] [ delimiter [as] char ] [ null [as] string ]
*
* \copy ( select stmt ) to filename
* [ with ] [ binary ] [ delimiter [as] char ] [ null [as] string ]
*
* The pre-7.3 syntax was:
* \copy [ binary ] tablename [(columnlist)] [with oids] from|to filename
* [ [using] delimiters char ] [ with null as string ]
...
...
@@ -142,6 +145,26 @@ parse_slash_copy(const char *args)
result
->
table
=
pg_strdup
(
token
);
/* Handle COPY (SELECT) case */
if
(
token
[
0
]
==
'('
)
{
int
parens
=
1
;
while
(
parens
>
0
)
{
token
=
strtokx
(
NULL
,
whitespace
,
".,()"
,
"
\"
'"
,
nonstd_backslash
,
true
,
false
,
pset
.
encoding
);
if
(
!
token
)
goto
error
;
if
(
token
[
0
]
==
'('
)
parens
++
;
else
if
(
token
[
0
]
==
')'
)
parens
--
;
xstrcat
(
&
result
->
table
,
" "
);
xstrcat
(
&
result
->
table
,
token
);
}
}
token
=
strtokx
(
NULL
,
whitespace
,
".,()"
,
"
\"
"
,
0
,
false
,
false
,
pset
.
encoding
);
if
(
!
token
)
...
...
src/include/commands/copy.h
View file @
85188ab8
...
...
@@ -7,7 +7,7 @@
* Portions Copyright (c) 1996-2006, PostgreSQL Global Development Group
* Portions Copyright (c) 1994, Regents of the University of California
*
* $PostgreSQL: pgsql/src/include/commands/copy.h,v 1.2
7 2006/03/05 15:58:55 momjian
Exp $
* $PostgreSQL: pgsql/src/include/commands/copy.h,v 1.2
8 2006/08/30 23:34:22 tgl
Exp $
*
*-------------------------------------------------------------------------
*/
...
...
@@ -15,8 +15,11 @@
#define COPY_H
#include "nodes/parsenodes.h"
#include "tcop/dest.h"
extern
uint64
DoCopy
(
const
CopyStmt
*
stmt
);
extern
DestReceiver
*
CreateCopyDestReceiver
(
void
);
#endif
/* COPY_H */
src/include/nodes/parsenodes.h
View file @
85188ab8
...
...
@@ -7,7 +7,7 @@
* Portions Copyright (c) 1996-2006, PostgreSQL Global Development Group
* Portions Copyright (c) 1994, Regents of the University of California
*
* $PostgreSQL: pgsql/src/include/nodes/parsenodes.h,v 1.32
5 2006/08/25 04:06:56
tgl Exp $
* $PostgreSQL: pgsql/src/include/nodes/parsenodes.h,v 1.32
6 2006/08/30 23:34:22
tgl Exp $
*
*-------------------------------------------------------------------------
*/
...
...
@@ -1012,16 +1012,22 @@ typedef struct GrantRoleStmt
/* ----------------------
* Copy Statement
*
* We support "COPY relation FROM file", "COPY relation TO file", and
* "COPY (query) TO file". In any given CopyStmt, exactly one of "relation"
* and "query" must be non-NULL. Note: "query" is a SelectStmt before
* parse analysis, and a Query afterwards.
* ----------------------
*/
typedef
struct
CopyStmt
{
NodeTag
type
;
RangeVar
*
relation
;
/* the relation to copy */
Query
*
query
;
/* the query to copy */
List
*
attlist
;
/* List of column names (as Strings), or NIL
* for all columns */
bool
is_from
;
/* TO or FROM */
char
*
filename
;
/*
if NULL, use stdin/stdout
*/
char
*
filename
;
/*
filename, or NULL for STDIN/STDOUT
*/
List
*
options
;
/* List of DefElem nodes */
}
CopyStmt
;
...
...
src/include/tcop/dest.h
View file @
85188ab8
...
...
@@ -54,7 +54,7 @@
* Portions Copyright (c) 1996-2006, PostgreSQL Global Development Group
* Portions Copyright (c) 1994, Regents of the University of California
*
* $PostgreSQL: pgsql/src/include/tcop/dest.h,v 1.5
1 2006/08/12 02:52:06
tgl Exp $
* $PostgreSQL: pgsql/src/include/tcop/dest.h,v 1.5
2 2006/08/30 23:34:22
tgl Exp $
*
*-------------------------------------------------------------------------
*/
...
...
@@ -85,7 +85,8 @@ typedef enum
DestRemoteExecute
,
/* sent to frontend, in Execute command */
DestSPI
,
/* results sent to SPI manager */
DestTuplestore
,
/* results sent to Tuplestore */
DestIntoRel
/* results sent to relation (SELECT INTO) */
DestIntoRel
,
/* results sent to relation (SELECT INTO) */
DestCopyOut
/* results sent to COPY TO code */
}
CommandDest
;
/* ----------------
...
...
src/test/regress/expected/copyselect.out
0 → 100644
View file @
85188ab8
--
-- Test cases for COPY (select) TO
--
create table test1 (id serial, t text);
NOTICE: CREATE TABLE will create implicit sequence "test1_id_seq" for serial column "test1.id"
insert into test1 (t) values ('a');
insert into test1 (t) values ('b');
insert into test1 (t) values ('c');
insert into test1 (t) values ('d');
insert into test1 (t) values ('e');
create table test2 (id serial, t text);
NOTICE: CREATE TABLE will create implicit sequence "test2_id_seq" for serial column "test2.id"
insert into test2 (t) values ('A');
insert into test2 (t) values ('B');
insert into test2 (t) values ('C');
insert into test2 (t) values ('D');
insert into test2 (t) values ('E');
create view v_test1
as select 'v_'||t from test1;
--
-- Test COPY table TO
--
copy test1 to stdout;
1 a
2 b
3 c
4 d
5 e
--
-- This should fail
--
copy v_test1 to stdout;
ERROR: cannot copy from view "v_test1"
HINT: Try the COPY (SELECT ...) TO variant.
--
-- Test COPY (select) TO
--
copy (select t from test1 where id=1) to stdout;
a
--
-- Test COPY (select for update) TO
--
copy (select t from test1 where id=3 for update) to stdout;
c
--
-- This should fail
--
copy (select t into temp test3 from test1 where id=3) to stdout;
ERROR: COPY (SELECT INTO) is not supported
--
-- This should fail
--
copy (select * from test1) from stdin;
ERROR: syntax error at or near "from"
LINE 1: copy (select * from test1) from stdin;
^
--
-- This should fail
--
copy (select * from test1) (t,id) to stdout;
ERROR: syntax error at or near "("
LINE 1: copy (select * from test1) (t,id) to stdout;
^
--
-- Test JOIN
--
copy (select * from test1 join test2 using (id)) to stdout;
1 a A
2 b B
3 c C
4 d D
5 e E
--
-- Test UNION SELECT
--
copy (select t from test1 where id = 1 UNION select * from v_test1) to stdout;
a
v_a
v_b
v_c
v_d
v_e
--
-- Test subselect
--
copy (select * from (select t from test1 where id = 1 UNION select * from v_test1) t1) to stdout;
a
v_a
v_b
v_c
v_d
v_e
--
-- Test headers, CSV and quotes
--
copy (select t from test1 where id = 1) to stdout csv header force quote t;
t
"a"
--
-- Test psql builtins, plain table
--
\copy test1 to stdout
1 a
2 b
3 c
4 d
5 e
--
-- This should fail
--
\copy v_test1 to stdout
ERROR: cannot copy from view "v_test1"
HINT: Try the COPY (SELECT ...) TO variant.
\copy: ERROR: cannot copy from view "v_test1"
HINT: Try the COPY (SELECT ...) TO variant.
--
-- Test \copy (select ...)
--
\copy (select "id",'id','id""'||t,(id + 1)*id,t,"test1"."t" from test1 where id=3) to stdout
3 id id""c 12 c c
--
-- Drop everything
--
drop table test2;
drop view v_test1;
drop table test1;
src/test/regress/parallel_schedule
View file @
85188ab8
# ----------
# The first group of parallel test
# $PostgreSQL: pgsql/src/test/regress/parallel_schedule,v 1.3
4 2006/08/12 02:52:06
tgl Exp $
# $PostgreSQL: pgsql/src/test/regress/parallel_schedule,v 1.3
5 2006/08/30 23:34:22
tgl Exp $
# ----------
test: boolean char name varchar text int2 int4 int8 oid float4 float8 bit numeric
...
...
@@ -34,7 +34,7 @@ test: create_function_2
# execute two copy tests parallel, to check that copy itself
# is concurrent safe.
# ----------
test: copy
test: copy
copyselect
# ----------
# The third group of parallel test
...
...
src/test/regress/serial_schedule
View file @
85188ab8
# $PostgreSQL: pgsql/src/test/regress/serial_schedule,v 1.3
2 2006/08/12 02:52:06
tgl Exp $
# $PostgreSQL: pgsql/src/test/regress/serial_schedule,v 1.3
3 2006/08/30 23:34:22
tgl Exp $
# This should probably be in an order similar to parallel_schedule.
test: boolean
test: char
...
...
@@ -43,6 +43,7 @@ test: create_type
test: create_table
test: create_function_2
test: copy
test: copyselect
test: constraints
test: triggers
test: create_misc
...
...
src/test/regress/sql/copyselect.sql
0 → 100644
View file @
85188ab8
--
-- Test cases for COPY (select) TO
--
create
table
test1
(
id
serial
,
t
text
);
insert
into
test1
(
t
)
values
(
'a'
);
insert
into
test1
(
t
)
values
(
'b'
);
insert
into
test1
(
t
)
values
(
'c'
);
insert
into
test1
(
t
)
values
(
'd'
);
insert
into
test1
(
t
)
values
(
'e'
);
create
table
test2
(
id
serial
,
t
text
);
insert
into
test2
(
t
)
values
(
'A'
);
insert
into
test2
(
t
)
values
(
'B'
);
insert
into
test2
(
t
)
values
(
'C'
);
insert
into
test2
(
t
)
values
(
'D'
);
insert
into
test2
(
t
)
values
(
'E'
);
create
view
v_test1
as
select
'v_'
||
t
from
test1
;
--
-- Test COPY table TO
--
copy
test1
to
stdout
;
--
-- This should fail
--
copy
v_test1
to
stdout
;
--
-- Test COPY (select) TO
--
copy
(
select
t
from
test1
where
id
=
1
)
to
stdout
;
--
-- Test COPY (select for update) TO
--
copy
(
select
t
from
test1
where
id
=
3
for
update
)
to
stdout
;
--
-- This should fail
--
copy
(
select
t
into
temp
test3
from
test1
where
id
=
3
)
to
stdout
;
--
-- This should fail
--
copy
(
select
*
from
test1
)
from
stdin
;
--
-- This should fail
--
copy
(
select
*
from
test1
)
(
t
,
id
)
to
stdout
;
--
-- Test JOIN
--
copy
(
select
*
from
test1
join
test2
using
(
id
))
to
stdout
;
--
-- Test UNION SELECT
--
copy
(
select
t
from
test1
where
id
=
1
UNION
select
*
from
v_test1
)
to
stdout
;
--
-- Test subselect
--
copy
(
select
*
from
(
select
t
from
test1
where
id
=
1
UNION
select
*
from
v_test1
)
t1
)
to
stdout
;
--
-- Test headers, CSV and quotes
--
copy
(
select
t
from
test1
where
id
=
1
)
to
stdout
csv
header
force
quote
t
;
--
-- Test psql builtins, plain table
--
\
copy
test1
to
stdout
--
-- This should fail
--
\
copy
v_test1
to
stdout
--
-- Test \copy (select ...)
--
\
copy
(
select
"id"
,
'id'
,
'id""'
||
t
,(
id
+
1
)
*
id
,
t
,
"test1"
.
"t"
from
test1
where
id
=
3
)
to
stdout
--
-- Drop everything
--
drop
table
test2
;
drop
view
v_test1
;
drop
table
test1
;
Write
Preview
Markdown
is supported
0%
Try again
or
attach a new file
Attach a file
Cancel
You are about to add
0
people
to the discussion. Proceed with caution.
Finish editing this message first!
Cancel
Please
register
or
sign in
to comment