<!--
-$PostgreSQL: pgsql/doc/src/sgml/ref/delete.sgml,v 1.22 2005/01/09 05:57:45 tgl Exp $
+$PostgreSQL: pgsql/doc/src/sgml/ref/delete.sgml,v 1.23 2005/04/07 01:51:37 neilc Exp $
PostgreSQL documentation
-->
<refsynopsisdiv>
<synopsis>
-DELETE FROM [ ONLY ] <replaceable class="PARAMETER">table</replaceable> [ WHERE <replaceable class="PARAMETER">condition</replaceable> ]
+DELETE FROM [ ONLY ] <replaceable class="PARAMETER">table</replaceable>
+ [ USING <replaceable class="PARAMETER">usinglist</replaceable> ]
+ [ WHERE <replaceable class="PARAMETER">condition</replaceable> ]
</synopsis>
</refsynopsisdiv>
<literal>ONLY</literal> clause.
</para>
+ <para>
+ There are two ways to delete rows in a table using information
+ contained in other tables in the database: using sub-selects, or
+ specifying additional tables in the <literal>USING</literal> clause.
+ Which technique is more appropriate depends on the specific
+ circumstances.
+ </para>
+
<para>
You must have the <literal>DELETE</literal> privilege on the table
to delete from it, as well as the <literal>SELECT</literal>
- privilege for any table whose values are read in the <replaceable
+ privilege for any table in the <literal>USING</literal> clause or
+ whose values are read in the <replaceable
class="parameter">condition</replaceable>.
</para>
</refsect1>
</listitem>
</varlistentry>
+ <varlistentry>
+ <term><replaceable class="PARAMETER">usinglist</replaceable></term>
+ <listitem>
+ <para>
+ A list of table expressions, allowing columns from other tables
+ to appear in the <literal>WHERE</> condition. This is similar
+ to the list of tables that can be specified in the <xref
+ linkend="sql-from" endterm="sql-from-title"> of a
+ <command>SELECT</command> statement; for example, an alias for
+ the table name can be specified.
+ </para>
+ </listitem>
+ </varlistentry>
+
<varlistentry>
<term><replaceable class="parameter">condition</replaceable></term>
<listitem>
<para>
<productname>PostgreSQL</productname> lets you reference columns of
- other tables in the <literal>WHERE</> condition. For example, to
- delete all films produced by a given producer, one might do
+ other tables in the <literal>WHERE</> condition by specifying the
+ other tables in the <literal>USING</literal> clause. For example,
+ to delete all films produced by a given producer, one might do
<programlisting>
-DELETE FROM films
+DELETE FROM films USING producers
WHERE producer_id = producers.id AND producers.name = 'foo';
</programlisting>
What is essentially happening here is a join between <structname>films</>
WHERE producer_id IN (SELECT id FROM producers WHERE name = 'foo');
</programlisting>
In some cases the join style is easier to write or faster to
- execute than the sub-select style. One objection to the join style
- is that there is no explicit list of what tables are being used,
- which makes the style somewhat error-prone; also it cannot handle
- self-joins.
+ execute than the sub-select style.
+ </para>
+
+ <para>
+ If <varname>add_missing_from</varname> is enabled, any relations
+ mentioned in the <literal>WHERE</literal> condition will be
+ implicitly added to the <literal>USING</literal> clause.
</para>
</refsect1>
<title>Compatibility</title>
<para>
- This command conforms to the SQL standard, except that the ability to
- reference other tables in the <literal>WHERE</> clause is a
- <productname>PostgreSQL</productname> extension.
+ This command conforms to the SQL standard, except that the
+ <literal>USING</> clause and the ability to reference other tables
+ in the <literal>WHERE</> clause are <productname>PostgreSQL</>
+ extensions.
</para>
</refsect1>
</refentry>
* Portions Copyright (c) 1994, Regents of the University of California
*
* IDENTIFICATION
- * $PostgreSQL: pgsql/src/backend/nodes/copyfuncs.c,v 1.300 2005/04/06 16:34:05 tgl Exp $
+ * $PostgreSQL: pgsql/src/backend/nodes/copyfuncs.c,v 1.301 2005/04/07 01:51:38 neilc Exp $
*
*-------------------------------------------------------------------------
*/
COPY_NODE_FIELD(relation);
COPY_NODE_FIELD(whereClause);
+ COPY_NODE_FIELD(usingClause);
return newnode;
}
* Portions Copyright (c) 1994, Regents of the University of California
*
* IDENTIFICATION
- * $PostgreSQL: pgsql/src/backend/nodes/equalfuncs.c,v 1.239 2005/04/06 16:34:05 tgl Exp $
+ * $PostgreSQL: pgsql/src/backend/nodes/equalfuncs.c,v 1.240 2005/04/07 01:51:38 neilc Exp $
*
*-------------------------------------------------------------------------
*/
{
COMPARE_NODE_FIELD(relation);
COMPARE_NODE_FIELD(whereClause);
+ COMPARE_NODE_FIELD(usingClause);
return true;
}
* Portions Copyright (c) 1996-2005, PostgreSQL Global Development Group
* Portions Copyright (c) 1994, Regents of the University of California
*
- * $PostgreSQL: pgsql/src/backend/parser/analyze.c,v 1.317 2005/04/06 16:34:06 tgl Exp $
+ * $PostgreSQL: pgsql/src/backend/parser/analyze.c,v 1.318 2005/04/07 01:51:38 neilc Exp $
*
*-------------------------------------------------------------------------
*/
qry->distinctClause = NIL;
+ /*
+ * The USING clause is non-standard SQL syntax, and is equivalent
+ * in functionality to the FROM list that can be specified for
+ * UPDATE. The USING keyword is used rather than FROM because FROM
+ * is already a keyword in the DELETE syntax.
+ */
+ transformFromClause(pstate, stmt->usingClause);
+
/* fix where clause */
qual = transformWhereClause(pstate, stmt->whereClause, "WHERE");
*
*
* IDENTIFICATION
- * $PostgreSQL: pgsql/src/backend/parser/gram.y,v 2.486 2005/03/31 22:46:11 tgl Exp $
+ * $PostgreSQL: pgsql/src/backend/parser/gram.y,v 2.487 2005/04/07 01:51:38 neilc Exp $
*
* HISTORY
* AUTHOR DATE MAJOR EVENT
transaction_mode_list_or_empty
TableFuncElementList
prep_type_clause prep_type_list
- execute_param_clause
+ execute_param_clause using_clause
%type <range> into_clause OptTempTableName
*
*****************************************************************************/
-DeleteStmt: DELETE_P FROM relation_expr where_clause
+DeleteStmt: DELETE_P FROM relation_expr using_clause where_clause
{
DeleteStmt *n = makeNode(DeleteStmt);
n->relation = $3;
- n->whereClause = $4;
+ n->usingClause = $4;
+ n->whereClause = $5;
$$ = (Node *)n;
}
;
+using_clause:
+ USING from_list { $$ = $2; }
+ | /*EMPTY*/ { $$ = NIL; }
+ ;
+
LockStmt: LOCK_P opt_table qualified_name_list opt_lock opt_nowait
{
LockStmt *n = makeNode(LockStmt);
*
*
* IDENTIFICATION
- * $PostgreSQL: pgsql/src/backend/parser/parse_relation.c,v 1.104 2005/04/06 16:34:06 tgl Exp $
+ * $PostgreSQL: pgsql/src/backend/parser/parse_relation.c,v 1.105 2005/04/07 01:51:39 neilc Exp $
*
*-------------------------------------------------------------------------
*/
RangeTblEntry *rte = rt_fetch(varno, pstate->p_rtable);
/* joins are always inFromCl, so no need to check */
+ Assert(rte->inFromCl);
/* use orig_pstate here to get the right sublevels_up */
newresult = scanRTEForColumn(orig_pstate, rte, colname);
/*
* Generate a warning or error about an implicit RTE, if appropriate.
*
- * If ADD_MISSING_FROM is not enabled, raise an error.
- *
- * Our current theory on warnings is that we should allow "SELECT foo.*"
- * but warn about a mixture of explicit and implicit RTEs.
+ * If ADD_MISSING_FROM is not enabled, raise an error. Otherwise, emit
+ * a warning.
*/
static void
warnAutoRange(ParseState *pstate, RangeVar *relation)
{
- bool foundInFromCl = false;
- ListCell *temp;
-
if (!add_missing_from)
{
if (pstate->parentParseState != NULL)
errmsg("missing FROM-clause entry for table \"%s\"",
relation->relname)));
}
-
- foreach(temp, pstate->p_rtable)
- {
- RangeTblEntry *rte = lfirst(temp);
-
- if (rte->inFromCl)
- {
- foundInFromCl = true;
- break;
- }
- }
- if (foundInFromCl)
+ else
{
+ /* just issue a warning */
if (pstate->parentParseState != NULL)
ereport(NOTICE,
(errcode(ERRCODE_UNDEFINED_TABLE),
* back to source text
*
* IDENTIFICATION
- * $PostgreSQL: pgsql/src/backend/utils/adt/ruleutils.c,v 1.190 2005/04/06 16:34:06 tgl Exp $
+ * $PostgreSQL: pgsql/src/backend/utils/adt/ruleutils.c,v 1.191 2005/04/07 01:51:39 neilc Exp $
*
* This software is copyrighted by Jan Wieck - Hamburg.
*
static void get_agg_expr(Aggref *aggref, deparse_context *context);
static void get_const_expr(Const *constval, deparse_context *context);
static void get_sublink_expr(SubLink *sublink, deparse_context *context);
-static void get_from_clause(Query *query, deparse_context *context);
+static void get_from_clause(Query *query, const char *prefix,
+ deparse_context *context);
static void get_from_clause_item(Node *jtnode, Query *query,
deparse_context *context);
static void get_from_clause_alias(Alias *alias, int varno,
}
/* Add the FROM clause if needed */
- get_from_clause(query, context);
+ get_from_clause(query, " FROM ", context);
/* Add the WHERE clause if given */
if (query->jointree->quals != NULL)
}
/* Add the FROM clause if needed */
- get_from_clause(query, context);
+ get_from_clause(query, " FROM ", context);
/* Finally add a WHERE clause if given */
if (query->jointree->quals != NULL)
only_marker(rte),
generate_relation_name(rte->relid));
+ /* Add the USING clause if given */
+ get_from_clause(query, " USING ", context);
+
/* Add a WHERE clause if given */
if (query->jointree->quals != NULL)
{
/* ----------
* get_from_clause - Parse back a FROM clause
+ *
+ * "prefix" is the keyword that denotes the start of the list of FROM
+ * elements. It is FROM when used to parse back SELECT and UPDATE, but
+ * is USING when parsing back DELETE.
* ----------
*/
static void
-get_from_clause(Query *query, deparse_context *context)
+get_from_clause(Query *query, const char *prefix, deparse_context *context)
{
StringInfo buf = context->buf;
bool first = true;
if (first)
{
- appendContextKeyword(context, " FROM ",
+ appendContextKeyword(context, prefix,
-PRETTYINDENT_STD, PRETTYINDENT_STD, 2);
first = false;
}
*
* Copyright (c) 2000-2005, PostgreSQL Global Development Group
*
- * $PostgreSQL: pgsql/src/bin/psql/tab-complete.c,v 1.123 2005/04/04 07:19:44 neilc Exp $
+ * $PostgreSQL: pgsql/src/bin/psql/tab-complete.c,v 1.124 2005/04/07 01:51:39 neilc Exp $
*/
/*----------------------------------------------------------------------
else if (pg_strcasecmp(prev2_wd, "DELETE") == 0 &&
pg_strcasecmp(prev_wd, "FROM") == 0)
COMPLETE_WITH_SCHEMA_QUERY(Query_for_list_of_tables, NULL);
- /* Complete DELETE FROM <table> with "WHERE" (perhaps a safe idea?) */
+ /* Complete DELETE FROM <table> */
else if (pg_strcasecmp(prev3_wd, "DELETE") == 0 &&
pg_strcasecmp(prev2_wd, "FROM") == 0)
- COMPLETE_WITH_CONST("WHERE");
+ {
+ static const char *const list_DELETE[] =
+ {"USING", "WHERE", "SET", NULL};
+
+ COMPLETE_WITH_LIST(list_DELETE);
+ }
+ /* XXX: implement tab completion for DELETE ... USING */
/* EXPLAIN */
* Portions Copyright (c) 1996-2005, PostgreSQL Global Development Group
* Portions Copyright (c) 1994, Regents of the University of California
*
- * $PostgreSQL: pgsql/src/include/nodes/parsenodes.h,v 1.276 2005/04/06 16:34:07 tgl Exp $
+ * $PostgreSQL: pgsql/src/include/nodes/parsenodes.h,v 1.277 2005/04/07 01:51:40 neilc Exp $
*
*-------------------------------------------------------------------------
*/
NodeTag type;
RangeVar *relation; /* relation to delete from */
Node *whereClause; /* qualifications */
+ List *usingClause; /* optional using clause for more tables */
} DeleteStmt;
/* ----------------------
ERROR: invalid input syntax for type abstime: "bad date format"
INSERT INTO ABSTIME_TBL (f1) VALUES ('Jun 10, 1843');
-- test abstime operators
-SELECT '' AS eight, ABSTIME_TBL.*;
+SELECT '' AS eight, * FROM ABSTIME_TBL;
eight | f1
-------+------------------------------
| Sun Jan 14 03:14:21 1973 PST
| invalid
(7 rows)
-SELECT '' AS six, ABSTIME_TBL.*
+SELECT '' AS six, * FROM ABSTIME_TBL
WHERE ABSTIME_TBL.f1 < abstime 'Jun 30, 2001';
six | f1
-----+------------------------------
| Sat May 10 23:59:12 1947 PST
(5 rows)
-SELECT '' AS six, ABSTIME_TBL.*
+SELECT '' AS six, * FROM ABSTIME_TBL
WHERE ABSTIME_TBL.f1 > abstime '-infinity';
six | f1
-----+------------------------------
| invalid
(6 rows)
-SELECT '' AS six, ABSTIME_TBL.*
+SELECT '' AS six, * FROM ABSTIME_TBL
WHERE abstime 'May 10, 1947 23:59:12' <> ABSTIME_TBL.f1;
six | f1
-----+------------------------------
| invalid
(6 rows)
-SELECT '' AS three, ABSTIME_TBL.*
+SELECT '' AS three, * FROM ABSTIME_TBL
WHERE abstime 'epoch' >= ABSTIME_TBL.f1;
three | f1
-------+------------------------------
| Sat May 10 23:59:12 1947 PST
(3 rows)
-SELECT '' AS four, ABSTIME_TBL.*
+SELECT '' AS four, * FROM ABSTIME_TBL
WHERE ABSTIME_TBL.f1 <= abstime 'Jan 14, 1973 03:14:21';
four | f1
------+------------------------------
| Sat May 10 23:59:12 1947 PST
(4 rows)
-SELECT '' AS four, ABSTIME_TBL.*
+SELECT '' AS four, * FROM ABSTIME_TBL
WHERE ABSTIME_TBL.f1 <?>
tinterval '["Apr 1 1950 00:00:00" "Dec 30 1999 23:00:00"]';
four | f1
INSERT INTO BOOLTBL1 (f1) VALUES (bool 'True');
INSERT INTO BOOLTBL1 (f1) VALUES (bool 'true');
-- BOOLTBL1 should be full of true's at this point
-SELECT '' AS t_3, BOOLTBL1.*;
+SELECT '' AS t_3, BOOLTBL1.* FROM BOOLTBL1;
t_3 | f1
-----+----
| t
VALUES (bool 'XXX');
ERROR: invalid input syntax for type boolean: "XXX"
-- BOOLTBL2 should be full of false's at this point
-SELECT '' AS f_4, BOOLTBL2.*;
+SELECT '' AS f_4, BOOLTBL2.* FROM BOOLTBL2;
f_4 | f1
-----+----
| f
(4 rows)
SELECT '' AS tf_12, BOOLTBL1.*, BOOLTBL2.*
+ FROM BOOLTBL1, BOOLTBL2
WHERE BOOLTBL2.f1 <> BOOLTBL1.f1;
tf_12 | f1 | f1
-------+----+----
(12 rows)
SELECT '' AS tf_12, BOOLTBL1.*, BOOLTBL2.*
+ FROM BOOLTBL1, BOOLTBL2
WHERE boolne(BOOLTBL2.f1,BOOLTBL1.f1);
tf_12 | f1 | f1
-------+----+----
(12 rows)
SELECT '' AS ff_4, BOOLTBL1.*, BOOLTBL2.*
+ FROM BOOLTBL1, BOOLTBL2
WHERE BOOLTBL2.f1 = BOOLTBL1.f1 and BOOLTBL1.f1 = bool 'false';
ff_4 | f1 | f1
------+----+----
(4 rows)
SELECT '' AS tf_12_ff_4, BOOLTBL1.*, BOOLTBL2.*
+ FROM BOOLTBL1, BOOLTBL2
WHERE BOOLTBL2.f1 = BOOLTBL1.f1 or BOOLTBL1.f1 = bool 'true'
ORDER BY BOOLTBL1.f1, BOOLTBL2.f1;
tf_12_ff_4 | f1 | f1
ERROR: invalid input syntax for type box: "(2.3, 4.5)"
INSERT INTO BOX_TBL (f1) VALUES ('asdfasdf(ad');
ERROR: invalid input syntax for type box: "asdfasdf(ad"
-SELECT '' AS four, BOX_TBL.*;
+SELECT '' AS four, * FROM BOX_TBL;
four | f1
------+---------------------
| (2,2),(0,0)
INSERT INTO CHAR_TBL (f1) VALUES ('cd');
ERROR: value too long for type character(1)
INSERT INTO CHAR_TBL (f1) VALUES ('c ');
-SELECT '' AS seven, CHAR_TBL.*;
+SELECT '' AS seven, * FROM CHAR_TBL;
seven | f1
-------+----
| a
INSERT INTO CHAR_TBL (f1) VALUES ('abcde');
ERROR: value too long for type character(4)
INSERT INTO CHAR_TBL (f1) VALUES ('abcd ');
-SELECT '' AS four, CHAR_TBL.*;
+SELECT '' AS four, * FROM CHAR_TBL;
four | f1
------+------
| a
INSERT INTO CHAR_TBL (f1) VALUES ('cd');
ERROR: value too long for type character(1)
INSERT INTO CHAR_TBL (f1) VALUES ('c ');
-SELECT '' AS seven, CHAR_TBL.*;
+SELECT '' AS seven, * FROM CHAR_TBL;
seven | f1
-------+----
| a
INSERT INTO CHAR_TBL (f1) VALUES ('abcde');
ERROR: value too long for type character(4)
INSERT INTO CHAR_TBL (f1) VALUES ('abcd ');
-SELECT '' AS four, CHAR_TBL.*;
+SELECT '' AS four, * FROM CHAR_TBL;
four | f1
------+------
| a
-- CLASS POPULATION
-- (any resemblance to real life is purely coincidental)
--
-INSERT INTO tenk2 VALUES (tenk1.*);
+INSERT INTO tenk2 SELECT * FROM tenk1;
SELECT * INTO TABLE onek2 FROM onek;
-INSERT INTO fast_emp4000 VALUES (slow_emp4000.*);
+INSERT INTO fast_emp4000 SELECT * FROM slow_emp4000;
SELECT *
INTO TABLE Bprime
FROM tenk1
-- a view should also be temporary if it references a temporary sequence
CREATE SEQUENCE seq1;
CREATE TEMPORARY SEQUENCE seq1_temp;
-CREATE VIEW v9 AS SELECT seq1.is_called;
-CREATE VIEW v13_temp AS SELECT seq1_temp.is_called;
+CREATE VIEW v9 AS SELECT seq1.is_called FROM seq1;
+CREATE VIEW v13_temp AS SELECT seq1_temp.is_called FROM seq1_temp;
NOTICE: view "v13_temp" will be a temporary view
SELECT relname FROM pg_class
WHERE relname LIKE 'v_'
-- FLOAT4
--
CREATE TABLE FLOAT4_TBL (f1 float4);
-INSERT INTO FLOAT4_TBL(f1) VALUES ('0.0');
-INSERT INTO FLOAT4_TBL(f1) VALUES ('1004.30');
-INSERT INTO FLOAT4_TBL(f1) VALUES ('-34.84');
+INSERT INTO FLOAT4_TBL(f1) VALUES (' 0.0');
+INSERT INTO FLOAT4_TBL(f1) VALUES ('1004.30 ');
+INSERT INTO FLOAT4_TBL(f1) VALUES (' -34.84 ');
INSERT INTO FLOAT4_TBL(f1) VALUES ('1.2345678901234e+20');
INSERT INTO FLOAT4_TBL(f1) VALUES ('1.2345678901234e-20');
-- test for over and under flow
NaN
(1 row)
-SELECT '' AS five, FLOAT4_TBL.*;
+SELECT '' AS five, * FROM FLOAT4_TBL;
five | f1
------+--------------
| 0
-- test divide by zero
SELECT '' AS bad, f.f1 / '0.0' from FLOAT4_TBL f;
ERROR: division by zero
-SELECT '' AS five, FLOAT4_TBL.*;
+SELECT '' AS five, * FROM FLOAT4_TBL;
five | f1
------+--------------
| 0
UPDATE FLOAT4_TBL
SET f1 = FLOAT4_TBL.f1 * '-1'
WHERE FLOAT4_TBL.f1 > '0.0';
-SELECT '' AS five, FLOAT4_TBL.*;
+SELECT '' AS five, * FROM FLOAT4_TBL;
five | f1
------+---------------
| 0
NaN
(1 row)
-SELECT '' AS five, FLOAT4_TBL.*;
+SELECT '' AS five, * FROM FLOAT4_TBL;
five | f1
------+-------------
| 0
-- test divide by zero
SELECT '' AS bad, f.f1 / '0.0' from FLOAT4_TBL f;
ERROR: division by zero
-SELECT '' AS five, FLOAT4_TBL.*;
+SELECT '' AS five, * FROM FLOAT4_TBL;
five | f1
------+-------------
| 0
UPDATE FLOAT4_TBL
SET f1 = FLOAT4_TBL.f1 * '-1'
WHERE FLOAT4_TBL.f1 > '0.0';
-SELECT '' AS five, FLOAT4_TBL.*;
+SELECT '' AS five, * FROM FLOAT4_TBL;
five | f1
------+--------------
| 0
-- FLOAT8
--
CREATE TABLE FLOAT8_TBL(f1 float8);
-INSERT INTO FLOAT8_TBL(f1) VALUES ('0.0');
-INSERT INTO FLOAT8_TBL(f1) VALUES ('1004.30');
-INSERT INTO FLOAT8_TBL(f1) VALUES ('-34.84');
+INSERT INTO FLOAT8_TBL(f1) VALUES (' 0.0 ');
+INSERT INTO FLOAT8_TBL(f1) VALUES ('1004.30 ');
+INSERT INTO FLOAT8_TBL(f1) VALUES (' -34.84');
INSERT INTO FLOAT8_TBL(f1) VALUES ('1.2345678901234e+200');
INSERT INTO FLOAT8_TBL(f1) VALUES ('1.2345678901234e-200');
-- test for underflow and overflow handling
NaN
(1 row)
-SELECT '' AS five, FLOAT8_TBL.*;
+SELECT '' AS five, * FROM FLOAT8_TBL;
five | f1
------+----------------------
| 0
| 1.2345678901234e-200 | 2.3112042409018e-067
(5 rows)
-SELECT '' AS five, FLOAT8_TBL.*;
+SELECT '' AS five, * FROM FLOAT8_TBL;
five | f1
------+----------------------
| 0
ERROR: result is out of range
SELECT '' AS bad, f.f1 / '0.0' from FLOAT8_TBL f;
ERROR: division by zero
-SELECT '' AS five, FLOAT8_TBL.*;
+SELECT '' AS five, * FROM FLOAT8_TBL;
five | f1
------+-----------------------
| 0
INSERT INTO FLOAT8_TBL(f1) VALUES ('-1004.30');
INSERT INTO FLOAT8_TBL(f1) VALUES ('-1.2345678901234e+200');
INSERT INTO FLOAT8_TBL(f1) VALUES ('-1.2345678901234e-200');
-SELECT '' AS five, FLOAT8_TBL.*;
+SELECT '' AS five, * FROM FLOAT8_TBL;
five | f1
------+-----------------------
| 0
NaN
(1 row)
-SELECT '' AS five, FLOAT8_TBL.*;
+SELECT '' AS five, * FROM FLOAT8_TBL;
five | f1
------+----------------------
| 0
| 1.2345678901234e-200 | 2.3112042409018e-067
(5 rows)
-SELECT '' AS five, FLOAT8_TBL.*;
+SELECT '' AS five, * FROM FLOAT8_TBL;
five | f1
------+----------------------
| 0
ERROR: result is out of range
SELECT '' AS bad, f.f1 / '0.0' from FLOAT8_TBL f;
ERROR: division by zero
-SELECT '' AS five, FLOAT8_TBL.*;
+SELECT '' AS five, * FROM FLOAT8_TBL;
five | f1
------+-----------------------
| 0
INSERT INTO FLOAT8_TBL(f1) VALUES ('-1004.30');
INSERT INTO FLOAT8_TBL(f1) VALUES ('-1.2345678901234e+200');
INSERT INTO FLOAT8_TBL(f1) VALUES ('-1.2345678901234e-200');
-SELECT '' AS five, FLOAT8_TBL.*;
+SELECT '' AS five, * FROM FLOAT8_TBL;
five | f1
------+-----------------------
| 0
NaN
(1 row)
-SELECT '' AS five, FLOAT8_TBL.*;
+SELECT '' AS five, * FROM FLOAT8_TBL;
five | f1
------+----------------------
| 0
| 1.2345678901234e-200 | 2.3112042409018e-67
(5 rows)
-SELECT '' AS five, FLOAT8_TBL.*;
+SELECT '' AS five, * FROM FLOAT8_TBL;
five | f1
------+----------------------
| 0
ERROR: result is out of range
SELECT '' AS bad, f.f1 / '0.0' from FLOAT8_TBL f;
ERROR: division by zero
-SELECT '' AS five, FLOAT8_TBL.*;
+SELECT '' AS five, * FROM FLOAT8_TBL;
five | f1
------+-----------------------
| 0
INSERT INTO FLOAT8_TBL(f1) VALUES ('-1004.30');
INSERT INTO FLOAT8_TBL(f1) VALUES ('-1.2345678901234e+200');
INSERT INTO FLOAT8_TBL(f1) VALUES ('-1.2345678901234e-200');
-SELECT '' AS five, FLOAT8_TBL.*;
+SELECT '' AS five, * FROM FLOAT8_TBL;
five | f1
------+-----------------------
| 0
NaN
(1 row)
-SELECT '' AS five, FLOAT8_TBL.*;
+SELECT '' AS five, * FROM FLOAT8_TBL;
five | f1
------+----------------------
| 0
| 1.2345678901234e-200 | 2.3112042409018e-67
(5 rows)
-SELECT '' AS five, FLOAT8_TBL.*;
+SELECT '' AS five, * FROM FLOAT8_TBL;
five | f1
------+----------------------
| 0
ERROR: result is out of range
SELECT '' AS bad, f.f1 / '0.0' from FLOAT8_TBL f;
ERROR: division by zero
-SELECT '' AS five, FLOAT8_TBL.*;
+SELECT '' AS five, * FROM FLOAT8_TBL;
five | f1
------+-----------------------
| 0
INSERT INTO FLOAT8_TBL(f1) VALUES ('-1004.30');
INSERT INTO FLOAT8_TBL(f1) VALUES ('-1.2345678901234e+200');
INSERT INTO FLOAT8_TBL(f1) VALUES ('-1.2345678901234e-200');
-SELECT '' AS five, FLOAT8_TBL.*;
+SELECT '' AS five, * FROM FLOAT8_TBL;
five | f1
------+-----------------------
| 0
NaN
(1 row)
-SELECT '' AS five, FLOAT8_TBL.*;
+SELECT '' AS five, * FROM FLOAT8_TBL;
five | f1
------+----------------------
| 0
| 1.2345678901234e-200 | 2.3112042409018e-67
(5 rows)
-SELECT '' AS five, FLOAT8_TBL.*;
+SELECT '' AS five, * FROM FLOAT8_TBL;
five | f1
------+----------------------
| 0
ERROR: result is out of range
SELECT '' AS bad, f.f1 / '0.0' from FLOAT8_TBL f;
ERROR: division by zero
-SELECT '' AS five, FLOAT8_TBL.*;
+SELECT '' AS five, * FROM FLOAT8_TBL;
five | f1
------+-----------------------
| 0
INSERT INTO FLOAT8_TBL(f1) VALUES ('-1004.30');
INSERT INTO FLOAT8_TBL(f1) VALUES ('-1.2345678901234e+200');
INSERT INTO FLOAT8_TBL(f1) VALUES ('-1.2345678901234e-200');
-SELECT '' AS five, FLOAT8_TBL.*;
+SELECT '' AS five, * FROM FLOAT8_TBL;
five | f1
------+-----------------------
| 0
-- HASH_INDEX
-- grep 843938989 hash.data
--
-SELECT hash_i4_heap.*
+SELECT * FROM hash_i4_heap
WHERE hash_i4_heap.random = 843938989;
seqno | random
-------+-----------
-- hash index
-- grep 66766766 hash.data
--
-SELECT hash_i4_heap.*
+SELECT * FROM hash_i4_heap
WHERE hash_i4_heap.random = 66766766;
seqno | random
-------+--------
-- hash index
-- grep 1505703298 hash.data
--
-SELECT hash_name_heap.*
+SELECT * FROM hash_name_heap
WHERE hash_name_heap.random = '1505703298'::name;
seqno | random
-------+------------
-- hash index
-- grep 7777777 hash.data
--
-SELECT hash_name_heap.*
+SELECT * FROM hash_name_heap
WHERE hash_name_heap.random = '7777777'::name;
seqno | random
-------+--------
-- hash index
-- grep 1351610853 hash.data
--
-SELECT hash_txt_heap.*
+SELECT * FROM hash_txt_heap
WHERE hash_txt_heap.random = '1351610853'::text;
seqno | random
-------+------------
-- hash index
-- grep 111111112222222233333333 hash.data
--
-SELECT hash_txt_heap.*
+SELECT * FROM hash_txt_heap
WHERE hash_txt_heap.random = '111111112222222233333333'::text;
seqno | random
-------+--------
-- hash index
-- grep 444705537 hash.data
--
-SELECT hash_f8_heap.*
+SELECT * FROM hash_f8_heap
WHERE hash_f8_heap.random = '444705537'::float8;
seqno | random
-------+-----------
-- hash index
-- grep 88888888 hash.data
--
-SELECT hash_f8_heap.*
+SELECT * FROM hash_f8_heap
WHERE hash_f8_heap.random = '88888888'::float8;
seqno | random
-------+--------
-- abstime, reltime arithmetic
--
SELECT '' AS ten, ABSTIME_TBL.f1 AS abstime, RELTIME_TBL.f1 AS reltime
+ FROM ABSTIME_TBL, RELTIME_TBL
WHERE (ABSTIME_TBL.f1 + RELTIME_TBL.f1) < abstime 'Jan 14 14:00:00 1971'
ORDER BY abstime, reltime;
ten | abstime | reltime
-- these four queries should return the same answer
-- the "infinity" and "-infinity" tuples in ABSTIME_TBL cannot be added and
-- therefore, should not show up in the results.
-SELECT '' AS three, ABSTIME_TBL.*
+SELECT '' AS three, * FROM ABSTIME_TBL
WHERE (ABSTIME_TBL.f1 + reltime '@ 3 year') -- +3 years
< abstime 'Jan 14 14:00:00 1977';
three | f1
| Sat May 10 23:59:12 1947 PST
(3 rows)
-SELECT '' AS three, ABSTIME_TBL.*
+SELECT '' AS three, * FROM ABSTIME_TBL
WHERE (ABSTIME_TBL.f1 + reltime '@ 3 year ago') -- -3 years
< abstime 'Jan 14 14:00:00 1971';
three | f1
| Sat May 10 23:59:12 1947 PST
(3 rows)
-SELECT '' AS three, ABSTIME_TBL.*
+SELECT '' AS three, * FROM ABSTIME_TBL
WHERE (ABSTIME_TBL.f1 - reltime '@ 3 year') -- -(+3) years
< abstime 'Jan 14 14:00:00 1971';
three | f1
| Sat May 10 23:59:12 1947 PST
(3 rows)
-SELECT '' AS three, ABSTIME_TBL.*
+SELECT '' AS three, * FROM ABSTIME_TBL
WHERE (ABSTIME_TBL.f1 - reltime '@ 3 year ago') -- -(-3) years
< abstime 'Jan 14 14:00:00 1977';
three | f1
ERROR: invalid input syntax for integer: "123 dt"
INSERT INTO INT2_TBL(f1) VALUES ('');
ERROR: invalid input syntax for integer: ""
-SELECT '' AS five, INT2_TBL.*;
+SELECT '' AS five, * FROM INT2_TBL;
five | f1
------+--------
| 0
ERROR: invalid input syntax for integer: "123 5"
INSERT INTO INT4_TBL(f1) VALUES ('');
ERROR: invalid input syntax for integer: ""
-SELECT '' AS five, INT4_TBL.*;
+SELECT '' AS five, * FROM INT4_TBL;
five | f1
------+-------------
| 0
INSERT INTO INTERVAL_TBL (f1) VALUES ('@ 30 eons ago');
ERROR: invalid input syntax for type interval: "@ 30 eons ago"
-- test interval operators
-SELECT '' AS ten, INTERVAL_TBL.*;
+SELECT '' AS ten, * FROM INTERVAL_TBL;
ten | f1
-----+-----------------
| 00:01:00
| 5 mons 12:00:00
(10 rows)
-SELECT '' AS nine, INTERVAL_TBL.*
+SELECT '' AS nine, * FROM INTERVAL_TBL
WHERE INTERVAL_TBL.f1 <> interval '@ 10 days';
nine | f1
------+-----------------
| 5 mons 12:00:00
(9 rows)
-SELECT '' AS three, INTERVAL_TBL.*
+SELECT '' AS three, * FROM INTERVAL_TBL
WHERE INTERVAL_TBL.f1 <= interval '@ 5 hours';
three | f1
-------+-----------
| -00:00:14
(3 rows)
-SELECT '' AS three, INTERVAL_TBL.*
+SELECT '' AS three, * FROM INTERVAL_TBL
WHERE INTERVAL_TBL.f1 < interval '@ 1 day';
three | f1
-------+-----------
| -00:00:14
(3 rows)
-SELECT '' AS one, INTERVAL_TBL.*
+SELECT '' AS one, * FROM INTERVAL_TBL
WHERE INTERVAL_TBL.f1 = interval '@ 34 years';
one | f1
-----+----------
| 34 years
(1 row)
-SELECT '' AS five, INTERVAL_TBL.*
+SELECT '' AS five, * FROM INTERVAL_TBL
WHERE INTERVAL_TBL.f1 >= interval '@ 1 month';
five | f1
------+-----------------
| 5 mons 12:00:00
(5 rows)
-SELECT '' AS nine, INTERVAL_TBL.*
+SELECT '' AS nine, * FROM INTERVAL_TBL
WHERE INTERVAL_TBL.f1 > interval '@ 3 seconds ago';
nine | f1
------+-----------------
(45 rows)
SET DATESTYLE = 'postgres';
-SELECT '' AS ten, INTERVAL_TBL.*;
+SELECT '' AS ten, * FROM INTERVAL_TBL;
ten | f1
-----+-------------------------------
| @ 1 min
DROP TABLE t3;
DROP TABLE J1_TBL;
DROP TABLE J2_TBL;
+-- Both DELETE and UPDATE allow the specification of additional tables
+-- to "join" against to determine which rows should be modified.
+CREATE TEMP TABLE t1 (a int, b int);
+CREATE TEMP TABLE t2 (a int, b int);
+CREATE TEMP TABLE t3 (x int, y int);
+INSERT INTO t1 VALUES (5, 10);
+INSERT INTO t1 VALUES (15, 20);
+INSERT INTO t1 VALUES (100, 100);
+INSERT INTO t1 VALUES (200, 1000);
+INSERT INTO t2 VALUES (200, 2000);
+INSERT INTO t3 VALUES (5, 20);
+INSERT INTO t3 VALUES (6, 7);
+INSERT INTO t3 VALUES (7, 8);
+INSERT INTO t3 VALUES (500, 100);
+DELETE FROM t3 USING t1 table1 WHERE t3.x = table1.a;
+SELECT * FROM t3;
+ x | y
+-----+-----
+ 6 | 7
+ 7 | 8
+ 500 | 100
+(3 rows)
+
+DELETE FROM t3 USING t1 JOIN t2 USING (a) WHERE t3.x > t1.a;
+SELECT * FROM t3;
+ x | y
+---+---
+ 6 | 7
+ 7 | 8
+(2 rows)
+
+DELETE FROM t3 USING t3 t3_other WHERE t3.x = t3_other.x AND t3.y = t3_other.y;
+SELECT * FROM t3;
+ x | y
+---+---
+(0 rows)
+
DROP TABLE t3;
DROP TABLE J1_TBL;
DROP TABLE J2_TBL;
+-- Both DELETE and UPDATE allow the specification of additional tables
+-- to "join" against to determine which rows should be modified.
+CREATE TEMP TABLE t1 (a int, b int);
+CREATE TEMP TABLE t2 (a int, b int);
+CREATE TEMP TABLE t3 (x int, y int);
+INSERT INTO t1 VALUES (5, 10);
+INSERT INTO t1 VALUES (15, 20);
+INSERT INTO t1 VALUES (100, 100);
+INSERT INTO t1 VALUES (200, 1000);
+INSERT INTO t2 VALUES (200, 2000);
+INSERT INTO t3 VALUES (5, 20);
+INSERT INTO t3 VALUES (6, 7);
+INSERT INTO t3 VALUES (7, 8);
+INSERT INTO t3 VALUES (500, 100);
+DELETE FROM t3 USING t1 table1 WHERE t3.x = table1.a;
+SELECT * FROM t3;
+ x | y
+-----+-----
+ 6 | 7
+ 7 | 8
+ 500 | 100
+(3 rows)
+
+DELETE FROM t3 USING t1 JOIN t2 USING (a) WHERE t3.x > t1.a;
+SELECT * FROM t3;
+ x | y
+---+---
+ 6 | 7
+ 7 | 8
+(2 rows)
+
+DELETE FROM t3 USING t3 t3_other WHERE t3.x = t3_other.x AND t3.y = t3_other.y;
+SELECT * FROM t3;
+ x | y
+---+---
+(0 rows)
INSERT INTO NAME_TBL(f1) VALUES ('d34aaasdf');
INSERT INTO NAME_TBL(f1) VALUES ('');
INSERT INTO NAME_TBL(f1) VALUES ('1234567890ABCDEFGHIJKLMNOPQRSTUVWXYZ1234567890ABCDEFGHIJKLMNOPQRSTUVWXYZ');
-SELECT '' AS seven, NAME_TBL.*;
+SELECT '' AS seven, * FROM NAME_TBL;
seven | f1
-------+-----------------------------------------------------------------
| 1234567890ABCDEFGHIJKLMNOPQRSTUVWXYZ1234567890ABCDEFGHIJKLMNOPQ
ERROR: value "32958209582039852935" is out of range for type oid
INSERT INTO OID_TBL(f1) VALUES ('-23582358720398502385');
ERROR: value "-23582358720398502385" is out of range for type oid
-SELECT '' AS six, OID_TBL.*;
+SELECT '' AS six, * FROM OID_TBL;
six | f1
-----+------------
| 1234
ERROR: invalid input syntax for type point: "(10.0 10.0)"
INSERT INTO POINT_TBL(f1) VALUES ('(10.0,10.0');
ERROR: invalid input syntax for type point: "(10.0,10.0"
-SELECT '' AS six, POINT_TBL.*;
+SELECT '' AS six, * FROM POINT_TBL;
six | f1
-----+------------
| (0,0)
ERROR: invalid input syntax for type polygon: "(0,1,2,3"
INSERT INTO POLYGON_TBL(f1) VALUES ('asdf');
ERROR: invalid input syntax for type polygon: "asdf"
-SELECT '' AS four, POLYGON_TBL.*;
+SELECT '' AS four, * FROM POLYGON_TBL;
four | f1
------+---------------------
| ((2,0),(2,4),(0,0))
UPDATE atest2 SET col2 = NULL; -- ok
UPDATE atest2 SET col2 = NOT col2; -- fails; requires SELECT on atest2
ERROR: permission denied for relation atest2
-UPDATE atest2 SET col2 = true WHERE atest1.a = 5; -- ok
+UPDATE atest2 SET col2 = true FROM atest1 WHERE atest1.a = 5; -- ok
SELECT * FROM atest1 FOR UPDATE; -- fail
ERROR: permission denied for relation atest1
SELECT * FROM atest2 FOR UPDATE; -- fail
INSERT INTO RELTIME_TBL (f1) VALUES ('@ 30 eons ago');
ERROR: invalid input syntax for type reltime: "@ 30 eons ago"
-- test reltime operators
-SELECT '' AS six, RELTIME_TBL.*;
+SELECT '' AS six, * FROM RELTIME_TBL;
six | f1
-----+---------------
| @ 1 min
| @ 14 secs ago
(6 rows)
-SELECT '' AS five, RELTIME_TBL.*
+SELECT '' AS five, * FROM RELTIME_TBL
WHERE RELTIME_TBL.f1 <> reltime '@ 10 days';
five | f1
------+---------------
| @ 14 secs ago
(5 rows)
-SELECT '' AS three, RELTIME_TBL.*
+SELECT '' AS three, * FROM RELTIME_TBL
WHERE RELTIME_TBL.f1 <= reltime '@ 5 hours';
three | f1
-------+---------------
| @ 14 secs ago
(3 rows)
-SELECT '' AS three, RELTIME_TBL.*
+SELECT '' AS three, * FROM RELTIME_TBL
WHERE RELTIME_TBL.f1 < reltime '@ 1 day';
three | f1
-------+---------------
| @ 14 secs ago
(3 rows)
-SELECT '' AS one, RELTIME_TBL.*
+SELECT '' AS one, * FROM RELTIME_TBL
WHERE RELTIME_TBL.f1 = reltime '@ 34 years';
one | f1
-----+------------
| @ 34 years
(1 row)
-SELECT '' AS two, RELTIME_TBL.*
+SELECT '' AS two, * FROM RELTIME_TBL
WHERE RELTIME_TBL.f1 >= reltime '@ 1 month';
two | f1
-----+------------
| @ 3 mons
(2 rows)
-SELECT '' AS five, RELTIME_TBL.*
+SELECT '' AS five, * FROM RELTIME_TBL
WHERE RELTIME_TBL.f1 > reltime '@ 3 seconds ago';
five | f1
------+------------
(3 rows)
delete from rtest_v1;
-insert into rtest_v1 select rtest_t2.a, rtest_t3.b where rtest_t2.a = rtest_t3.a;
+insert into rtest_v1 select rtest_t2.a, rtest_t3.b
+ from rtest_t2, rtest_t3
+ where rtest_t2.a = rtest_t3.a;
select * from rtest_v1;
a | b
---+----
(3 rows)
-- updates in a mergejoin
-update rtest_v1 set b = rtest_t2.b where a = rtest_t2.a;
+update rtest_v1 set b = rtest_t2.b from rtest_t2 where rtest_v1.a = rtest_t2.a;
select * from rtest_v1;
a | b
---+----
15 | 35
(8 rows)
-update rtest_v1 set a = rtest_t3.a + 20 where b = rtest_t3.b;
+update rtest_v1 set a = rtest_t3.a + 20 from rtest_t3 where rtest_v1.b = rtest_t3.b;
select * from rtest_v1;
a | b
----+----
(8 rows)
update rtest_empmass set salary = salary + '1000.00';
-update rtest_emp set salary = rtest_empmass.salary where ename = rtest_empmass.ename;
+update rtest_emp set salary = rtest_empmass.salary from rtest_empmass where rtest_emp.ename = rtest_empmass.ename;
select ename, who = current_user as "matches user", action, newsal, oldsal from rtest_emplog order by ename, action, newsal;
ename | matches user | action | newsal | oldsal
----------------------+--------------+------------+------------+------------
wieck | t | honored | $7,000.00 | $6,000.00
(11 rows)
-delete from rtest_emp where ename = rtest_empmass.ename;
+delete from rtest_emp using rtest_empmass where rtest_emp.ename = rtest_empmass.ename;
select ename, who = current_user as "matches user", action, newsal, oldsal from rtest_emplog order by ename, action, newsal;
ename | matches user | action | newsal | oldsal
----------------------+--------------+------------+------------+------------
-- btree index
-- awk '{if($1<10){print;}else{next;}}' onek.data | sort +0n -1
--
-SELECT onek.* WHERE onek.unique1 < 10
+SELECT * FROM onek
+ WHERE onek.unique1 < 10
ORDER BY onek.unique1;
unique1 | unique2 | two | four | ten | twenty | hundred | thousand | twothousand | fivethous | tenthous | odd | even | stringu1 | stringu2 | string4
---------+---------+-----+------+-----+--------+---------+----------+-------------+-----------+----------+-----+------+----------+----------+---------
--
-- awk '{if($1<20){print $1,$14;}else{next;}}' onek.data | sort +0nr -1
--
-SELECT onek.unique1, onek.stringu1
+SELECT onek.unique1, onek.stringu1 FROM onek
WHERE onek.unique1 < 20
ORDER BY unique1 using >;
unique1 | stringu1
--
-- awk '{if($1>980){print $1,$14;}else{next;}}' onek.data | sort +1d -2
--
-SELECT onek.unique1, onek.stringu1
+SELECT onek.unique1, onek.stringu1 FROM onek
WHERE onek.unique1 > 980
ORDER BY stringu1 using <;
unique1 | stringu1
-- awk '{if($1>980){print $1,$16;}else{next;}}' onek.data |
-- sort +1d -2 +0nr -1
--
-SELECT onek.unique1, onek.string4
+SELECT onek.unique1, onek.string4 FROM onek
WHERE onek.unique1 > 980
ORDER BY string4 using <, unique1 using >;
unique1 | string4
-- awk '{if($1>980){print $1,$16;}else{next;}}' onek.data |
-- sort +1dr -2 +0n -1
--
-SELECT onek.unique1, onek.string4
+SELECT onek.unique1, onek.string4 FROM onek
WHERE onek.unique1 > 980
ORDER BY string4 using >, unique1 using <;
unique1 | string4
-- awk '{if($1<20){print $1,$16;}else{next;}}' onek.data |
-- sort +0nr -1 +1d -2
--
-SELECT onek.unique1, onek.string4
+SELECT onek.unique1, onek.string4 FROM onek
WHERE onek.unique1 < 20
ORDER BY unique1 using >, string4 using <;
unique1 | string4
-- awk '{if($1<20){print $1,$16;}else{next;}}' onek.data |
-- sort +0n -1 +1dr -2
--
-SELECT onek.unique1, onek.string4
+SELECT onek.unique1, onek.string4 FROM onek
WHERE onek.unique1 < 20
ORDER BY unique1 using <, string4 using >;
unique1 | string4
--
-- awk '{if($1<10){print $0;}else{next;}}' onek.data | sort +0n -1
--
-SELECT onek2.* WHERE onek2.unique1 < 10;
+SELECT onek2.* FROM onek2 WHERE onek2.unique1 < 10;
unique1 | unique2 | two | four | ten | twenty | hundred | thousand | twothousand | fivethous | tenthous | odd | even | stringu1 | stringu2 | string4
---------+---------+-----+------+-----+--------+---------+----------+-------------+-----------+----------+-----+------+----------+----------+---------
0 | 998 | 0 | 0 | 0 | 0 | 0 | 0 | 0 | 0 | 0 | 0 | 1 | AAAAAA | KMBAAA | OOOOxx
--
-- awk '{if($1<20){print $1,$14;}else{next;}}' onek.data | sort +0nr -1
--
-SELECT onek2.unique1, onek2.stringu1
+SELECT onek2.unique1, onek2.stringu1 FROM onek2
WHERE onek2.unique1 < 20
ORDER BY unique1 using >;
unique1 | stringu1
--
-- awk '{if($1>980){print $1,$14;}else{next;}}' onek.data | sort +1d -2
--
-SELECT onek2.unique1, onek2.stringu1
+SELECT onek2.unique1, onek2.stringu1 FROM onek2
WHERE onek2.unique1 > 980;
unique1 | stringu1
---------+----------
VALUES ('["" "infinity"]');
ERROR: invalid input syntax for type abstime: ""
-- test tinterval operators
-SELECT '' AS five, TINTERVAL_TBL.*;
+SELECT '' AS five, * FROM TINTERVAL_TBL;
five | f1
------+-----------------------------------------------------------------
| ["-infinity" "infinity"]
(0 rows)
DELETE FROM temptest; -- ok
-UPDATE temptest SET a = 0 WHERE a = 1 AND writetest.a = temptest.a; -- ok
+UPDATE temptest SET a = 0 FROM writetest WHERE temptest.a = 1 AND writetest.a = temptest.a; -- ok
PREPARE test AS UPDATE writetest SET a = 0; -- ok
EXECUTE test; -- fail
ERROR: transaction is read-only
INSERT INTO VARCHAR_TBL (f1) VALUES ('cd');
ERROR: value too long for type character varying(1)
INSERT INTO VARCHAR_TBL (f1) VALUES ('c ');
-SELECT '' AS seven, VARCHAR_TBL.*;
+SELECT '' AS seven, * FROM VARCHAR_TBL;
seven | f1
-------+----
| a
INSERT INTO VARCHAR_TBL (f1) VALUES ('abcde');
ERROR: value too long for type character varying(4)
INSERT INTO VARCHAR_TBL (f1) VALUES ('abcd ');
-SELECT '' AS four, VARCHAR_TBL.*;
+SELECT '' AS four, * FROM VARCHAR_TBL;
four | f1
------+------
| a
INSERT INTO VARCHAR_TBL (f1) VALUES ('cd');
ERROR: value too long for type character varying(1)
INSERT INTO VARCHAR_TBL (f1) VALUES ('c ');
-SELECT '' AS seven, VARCHAR_TBL.*;
+SELECT '' AS seven, * FROM VARCHAR_TBL;
seven | f1
-------+----
| a
INSERT INTO VARCHAR_TBL (f1) VALUES ('abcde');
ERROR: value too long for type character varying(4)
INSERT INTO VARCHAR_TBL (f1) VALUES ('abcd ');
-SELECT '' AS four, VARCHAR_TBL.*;
+SELECT '' AS four, * FROM VARCHAR_TBL;
four | f1
------+------
| a
--
UPDATE tmp
SET stringu1 = reverse_name(onek.stringu1)
+ FROM onek
WHERE onek.stringu1 = 'JBAAAA' and
onek.stringu1 = tmp.stringu1;
UPDATE tmp
SET stringu1 = reverse_name(onek2.stringu1)
+ FROM onek2
WHERE onek2.stringu1 = 'JCAAAA' and
onek2.stringu1 = tmp.stringu1;
-- test abstime operators
-SELECT '' AS eight, ABSTIME_TBL.*;
+SELECT '' AS eight, * FROM ABSTIME_TBL;
-SELECT '' AS six, ABSTIME_TBL.*
+SELECT '' AS six, * FROM ABSTIME_TBL
WHERE ABSTIME_TBL.f1 < abstime 'Jun 30, 2001';
-SELECT '' AS six, ABSTIME_TBL.*
+SELECT '' AS six, * FROM ABSTIME_TBL
WHERE ABSTIME_TBL.f1 > abstime '-infinity';
-SELECT '' AS six, ABSTIME_TBL.*
+SELECT '' AS six, * FROM ABSTIME_TBL
WHERE abstime 'May 10, 1947 23:59:12' <> ABSTIME_TBL.f1;
-SELECT '' AS three, ABSTIME_TBL.*
+SELECT '' AS three, * FROM ABSTIME_TBL
WHERE abstime 'epoch' >= ABSTIME_TBL.f1;
-SELECT '' AS four, ABSTIME_TBL.*
+SELECT '' AS four, * FROM ABSTIME_TBL
WHERE ABSTIME_TBL.f1 <= abstime 'Jan 14, 1973 03:14:21';
-SELECT '' AS four, ABSTIME_TBL.*
+SELECT '' AS four, * FROM ABSTIME_TBL
WHERE ABSTIME_TBL.f1 <?>
tinterval '["Apr 1 1950 00:00:00" "Dec 30 1999 23:00:00"]';
-- BOOLTBL1 should be full of true's at this point
-SELECT '' AS t_3, BOOLTBL1.*;
+SELECT '' AS t_3, BOOLTBL1.* FROM BOOLTBL1;
SELECT '' AS t_3, BOOLTBL1.*
VALUES (bool 'XXX');
-- BOOLTBL2 should be full of false's at this point
-SELECT '' AS f_4, BOOLTBL2.*;
+SELECT '' AS f_4, BOOLTBL2.* FROM BOOLTBL2;
SELECT '' AS tf_12, BOOLTBL1.*, BOOLTBL2.*
+ FROM BOOLTBL1, BOOLTBL2
WHERE BOOLTBL2.f1 <> BOOLTBL1.f1;
SELECT '' AS tf_12, BOOLTBL1.*, BOOLTBL2.*
+ FROM BOOLTBL1, BOOLTBL2
WHERE boolne(BOOLTBL2.f1,BOOLTBL1.f1);
SELECT '' AS ff_4, BOOLTBL1.*, BOOLTBL2.*
+ FROM BOOLTBL1, BOOLTBL2
WHERE BOOLTBL2.f1 = BOOLTBL1.f1 and BOOLTBL1.f1 = bool 'false';
SELECT '' AS tf_12_ff_4, BOOLTBL1.*, BOOLTBL2.*
+ FROM BOOLTBL1, BOOLTBL2
WHERE BOOLTBL2.f1 = BOOLTBL1.f1 or BOOLTBL1.f1 = bool 'true'
ORDER BY BOOLTBL1.f1, BOOLTBL2.f1;
INSERT INTO BOX_TBL (f1) VALUES ('asdfasdf(ad');
-SELECT '' AS four, BOX_TBL.*;
+SELECT '' AS four, * FROM BOX_TBL;
SELECT '' AS four, b.*, area(b.f1) as barea
FROM BOX_TBL b;
INSERT INTO CHAR_TBL (f1) VALUES ('c ');
-SELECT '' AS seven, CHAR_TBL.*;
+SELECT '' AS seven, * FROM CHAR_TBL;
SELECT '' AS six, c.*
FROM CHAR_TBL c
INSERT INTO CHAR_TBL (f1) VALUES ('abcde');
INSERT INTO CHAR_TBL (f1) VALUES ('abcd ');
-SELECT '' AS four, CHAR_TBL.*;
+SELECT '' AS four, * FROM CHAR_TBL;
-- (any resemblance to real life is purely coincidental)
--
-INSERT INTO tenk2 VALUES (tenk1.*);
+INSERT INTO tenk2 SELECT * FROM tenk1;
SELECT * INTO TABLE onek2 FROM onek;
-
-INSERT INTO fast_emp4000 VALUES (slow_emp4000.*);
+INSERT INTO fast_emp4000 SELECT * FROM slow_emp4000;
SELECT *
INTO TABLE Bprime
-- a view should also be temporary if it references a temporary sequence
CREATE SEQUENCE seq1;
CREATE TEMPORARY SEQUENCE seq1_temp;
-CREATE VIEW v9 AS SELECT seq1.is_called;
-CREATE VIEW v13_temp AS SELECT seq1_temp.is_called;
+CREATE VIEW v9 AS SELECT seq1.is_called FROM seq1;
+CREATE VIEW v13_temp AS SELECT seq1_temp.is_called FROM seq1_temp;
SELECT relname FROM pg_class
WHERE relname LIKE 'v_'
SELECT 'nan'::float4 / 'nan'::float4;
-SELECT '' AS five, FLOAT4_TBL.*;
+SELECT '' AS five, * FROM FLOAT4_TBL;
SELECT '' AS four, f.* FROM FLOAT4_TBL f WHERE f.f1 <> '1004.3';
-- test divide by zero
SELECT '' AS bad, f.f1 / '0.0' from FLOAT4_TBL f;
-SELECT '' AS five, FLOAT4_TBL.*;
+SELECT '' AS five, * FROM FLOAT4_TBL;
-- test the unary float4abs operator
SELECT '' AS five, f.f1, @f.f1 AS abs_f1 FROM FLOAT4_TBL f;
SET f1 = FLOAT4_TBL.f1 * '-1'
WHERE FLOAT4_TBL.f1 > '0.0';
-SELECT '' AS five, FLOAT4_TBL.*;
+SELECT '' AS five, * FROM FLOAT4_TBL;
SELECT 'Infinity'::float8 / 'Infinity'::float8;
SELECT 'nan'::float8 / 'nan'::float8;
-SELECT '' AS five, FLOAT8_TBL.*;
+SELECT '' AS five, * FROM FLOAT8_TBL;
SELECT '' AS four, f.* FROM FLOAT8_TBL f WHERE f.f1 <> '1004.3';
SELECT '' AS five, f.f1, ||/f.f1 AS cbrt_f1 FROM FLOAT8_TBL f;
-SELECT '' AS five, FLOAT8_TBL.*;
+SELECT '' AS five, * FROM FLOAT8_TBL;
UPDATE FLOAT8_TBL
SET f1 = FLOAT8_TBL.f1 * '-1'
SELECT '' AS bad, f.f1 / '0.0' from FLOAT8_TBL f;
-SELECT '' AS five, FLOAT8_TBL.*;
+SELECT '' AS five, * FROM FLOAT8_TBL;
-- test for over- and underflow
INSERT INTO FLOAT8_TBL(f1) VALUES ('10e400');
INSERT INTO FLOAT8_TBL(f1) VALUES ('-1.2345678901234e-200');
-SELECT '' AS five, FLOAT8_TBL.*;
+SELECT '' AS five, * FROM FLOAT8_TBL;
-- grep 843938989 hash.data
--
-SELECT hash_i4_heap.*
+SELECT * FROM hash_i4_heap
WHERE hash_i4_heap.random = 843938989;
--
-- hash index
-- grep 66766766 hash.data
--
-SELECT hash_i4_heap.*
+SELECT * FROM hash_i4_heap
WHERE hash_i4_heap.random = 66766766;
--
-- hash index
-- grep 1505703298 hash.data
--
-SELECT hash_name_heap.*
+SELECT * FROM hash_name_heap
WHERE hash_name_heap.random = '1505703298'::name;
--
-- hash index
-- grep 7777777 hash.data
--
-SELECT hash_name_heap.*
+SELECT * FROM hash_name_heap
WHERE hash_name_heap.random = '7777777'::name;
--
-- hash index
-- grep 1351610853 hash.data
--
-SELECT hash_txt_heap.*
+SELECT * FROM hash_txt_heap
WHERE hash_txt_heap.random = '1351610853'::text;
--
-- hash index
-- grep 111111112222222233333333 hash.data
--
-SELECT hash_txt_heap.*
+SELECT * FROM hash_txt_heap
WHERE hash_txt_heap.random = '111111112222222233333333'::text;
--
-- hash index
-- grep 444705537 hash.data
--
-SELECT hash_f8_heap.*
+SELECT * FROM hash_f8_heap
WHERE hash_f8_heap.random = '444705537'::float8;
--
-- hash index
-- grep 88888888 hash.data
--
-SELECT hash_f8_heap.*
+SELECT * FROM hash_f8_heap
WHERE hash_f8_heap.random = '88888888'::float8;
--
--
SELECT '' AS ten, ABSTIME_TBL.f1 AS abstime, RELTIME_TBL.f1 AS reltime
+ FROM ABSTIME_TBL, RELTIME_TBL
WHERE (ABSTIME_TBL.f1 + RELTIME_TBL.f1) < abstime 'Jan 14 14:00:00 1971'
ORDER BY abstime, reltime;
-- the "infinity" and "-infinity" tuples in ABSTIME_TBL cannot be added and
-- therefore, should not show up in the results.
-SELECT '' AS three, ABSTIME_TBL.*
+SELECT '' AS three, * FROM ABSTIME_TBL
WHERE (ABSTIME_TBL.f1 + reltime '@ 3 year') -- +3 years
< abstime 'Jan 14 14:00:00 1977';
-SELECT '' AS three, ABSTIME_TBL.*
+SELECT '' AS three, * FROM ABSTIME_TBL
WHERE (ABSTIME_TBL.f1 + reltime '@ 3 year ago') -- -3 years
< abstime 'Jan 14 14:00:00 1971';
-SELECT '' AS three, ABSTIME_TBL.*
+SELECT '' AS three, * FROM ABSTIME_TBL
WHERE (ABSTIME_TBL.f1 - reltime '@ 3 year') -- -(+3) years
< abstime 'Jan 14 14:00:00 1971';
-SELECT '' AS three, ABSTIME_TBL.*
+SELECT '' AS three, * FROM ABSTIME_TBL
WHERE (ABSTIME_TBL.f1 - reltime '@ 3 year ago') -- -(-3) years
< abstime 'Jan 14 14:00:00 1977';
INSERT INTO INT2_TBL(f1) VALUES ('');
-SELECT '' AS five, INT2_TBL.*;
+SELECT '' AS five, * FROM INT2_TBL;
SELECT '' AS four, i.* FROM INT2_TBL i WHERE i.f1 <> int2 '0';
INSERT INTO INT4_TBL(f1) VALUES ('');
-SELECT '' AS five, INT4_TBL.*;
+SELECT '' AS five, * FROM INT4_TBL;
SELECT '' AS four, i.* FROM INT4_TBL i WHERE i.f1 <> int2 '0';
-- test interval operators
-SELECT '' AS ten, INTERVAL_TBL.*;
+SELECT '' AS ten, * FROM INTERVAL_TBL;
-SELECT '' AS nine, INTERVAL_TBL.*
+SELECT '' AS nine, * FROM INTERVAL_TBL
WHERE INTERVAL_TBL.f1 <> interval '@ 10 days';
-SELECT '' AS three, INTERVAL_TBL.*
+SELECT '' AS three, * FROM INTERVAL_TBL
WHERE INTERVAL_TBL.f1 <= interval '@ 5 hours';
-SELECT '' AS three, INTERVAL_TBL.*
+SELECT '' AS three, * FROM INTERVAL_TBL
WHERE INTERVAL_TBL.f1 < interval '@ 1 day';
-SELECT '' AS one, INTERVAL_TBL.*
+SELECT '' AS one, * FROM INTERVAL_TBL
WHERE INTERVAL_TBL.f1 = interval '@ 34 years';
-SELECT '' AS five, INTERVAL_TBL.*
+SELECT '' AS five, * FROM INTERVAL_TBL
WHERE INTERVAL_TBL.f1 >= interval '@ 1 month';
-SELECT '' AS nine, INTERVAL_TBL.*
+SELECT '' AS nine, * FROM INTERVAL_TBL
WHERE INTERVAL_TBL.f1 > interval '@ 3 seconds ago';
SELECT '' AS fortyfive, r1.*, r2.*
SET DATESTYLE = 'postgres';
-SELECT '' AS ten, INTERVAL_TBL.*;
+SELECT '' AS ten, * FROM INTERVAL_TBL;
-- test avg(interval), which is somewhat fragile since people have been
-- known to change the allowed input syntax for type interval without
DROP TABLE J1_TBL;
DROP TABLE J2_TBL;
+
+-- Both DELETE and UPDATE allow the specification of additional tables
+-- to "join" against to determine which rows should be modified.
+
+CREATE TEMP TABLE t1 (a int, b int);
+CREATE TEMP TABLE t2 (a int, b int);
+CREATE TEMP TABLE t3 (x int, y int);
+
+INSERT INTO t1 VALUES (5, 10);
+INSERT INTO t1 VALUES (15, 20);
+INSERT INTO t1 VALUES (100, 100);
+INSERT INTO t1 VALUES (200, 1000);
+INSERT INTO t2 VALUES (200, 2000);
+INSERT INTO t3 VALUES (5, 20);
+INSERT INTO t3 VALUES (6, 7);
+INSERT INTO t3 VALUES (7, 8);
+INSERT INTO t3 VALUES (500, 100);
+
+DELETE FROM t3 USING t1 table1 WHERE t3.x = table1.a;
+SELECT * FROM t3;
+DELETE FROM t3 USING t1 JOIN t2 USING (a) WHERE t3.x > t1.a;
+SELECT * FROM t3;
+DELETE FROM t3 USING t3 t3_other WHERE t3.x = t3_other.x AND t3.y = t3_other.y;
+SELECT * FROM t3;
\ No newline at end of file
INSERT INTO NAME_TBL(f1) VALUES ('1234567890ABCDEFGHIJKLMNOPQRSTUVWXYZ1234567890ABCDEFGHIJKLMNOPQRSTUVWXYZ');
-SELECT '' AS seven, NAME_TBL.*;
+SELECT '' AS seven, * FROM NAME_TBL;
SELECT '' AS six, c.f1 FROM NAME_TBL c WHERE c.f1 <> '1234567890ABCDEFGHIJKLMNOPQRSTUVWXYZ1234567890ABCDEFGHIJKLMNOPQR';
INSERT INTO OID_TBL(f1) VALUES ('32958209582039852935');
INSERT INTO OID_TBL(f1) VALUES ('-23582358720398502385');
-SELECT '' AS six, OID_TBL.*;
-
+SELECT '' AS six, * FROM OID_TBL;
SELECT '' AS one, o.* FROM OID_TBL o WHERE o.f1 = 1234;
INSERT INTO POINT_TBL(f1) VALUES ('(10.0,10.0');
-SELECT '' AS six, POINT_TBL.*;
+SELECT '' AS six, * FROM POINT_TBL;
-- left of
SELECT '' AS three, p.* FROM POINT_TBL p WHERE p.f1 << '(0.0, 0.0)';
INSERT INTO POLYGON_TBL(f1) VALUES ('asdf');
-SELECT '' AS four, POLYGON_TBL.*;
+SELECT '' AS four, * FROM POLYGON_TBL;
-- overlap
SELECT '' AS three, p.*
UPDATE atest1 SET a = 1 WHERE a = 2; -- fail
UPDATE atest2 SET col2 = NULL; -- ok
UPDATE atest2 SET col2 = NOT col2; -- fails; requires SELECT on atest2
-UPDATE atest2 SET col2 = true WHERE atest1.a = 5; -- ok
+UPDATE atest2 SET col2 = true FROM atest1 WHERE atest1.a = 5; -- ok
SELECT * FROM atest1 FOR UPDATE; -- fail
SELECT * FROM atest2 FOR UPDATE; -- fail
DELETE FROM atest2; -- fail
-- test reltime operators
-SELECT '' AS six, RELTIME_TBL.*;
+SELECT '' AS six, * FROM RELTIME_TBL;
-SELECT '' AS five, RELTIME_TBL.*
+SELECT '' AS five, * FROM RELTIME_TBL
WHERE RELTIME_TBL.f1 <> reltime '@ 10 days';
-SELECT '' AS three, RELTIME_TBL.*
+SELECT '' AS three, * FROM RELTIME_TBL
WHERE RELTIME_TBL.f1 <= reltime '@ 5 hours';
-SELECT '' AS three, RELTIME_TBL.*
+SELECT '' AS three, * FROM RELTIME_TBL
WHERE RELTIME_TBL.f1 < reltime '@ 1 day';
-SELECT '' AS one, RELTIME_TBL.*
+SELECT '' AS one, * FROM RELTIME_TBL
WHERE RELTIME_TBL.f1 = reltime '@ 34 years';
-SELECT '' AS two, RELTIME_TBL.*
+SELECT '' AS two, * FROM RELTIME_TBL
WHERE RELTIME_TBL.f1 >= reltime '@ 1 month';
-SELECT '' AS five, RELTIME_TBL.*
+SELECT '' AS five, * FROM RELTIME_TBL
WHERE RELTIME_TBL.f1 > reltime '@ 3 seconds ago';
SELECT '' AS fifteen, r1.*, r2.*
FROM RELTIME_TBL r1, RELTIME_TBL r2
WHERE r1.f1 > r2.f1
ORDER BY r1.f1, r2.f1;
-
update rtest_v1 set b = 88 where b < 50;
select * from rtest_v1;
delete from rtest_v1;
-insert into rtest_v1 select rtest_t2.a, rtest_t3.b where rtest_t2.a = rtest_t3.a;
+insert into rtest_v1 select rtest_t2.a, rtest_t3.b
+ from rtest_t2, rtest_t3
+ where rtest_t2.a = rtest_t3.a;
select * from rtest_v1;
-- updates in a mergejoin
-update rtest_v1 set b = rtest_t2.b where a = rtest_t2.a;
+update rtest_v1 set b = rtest_t2.b from rtest_t2 where rtest_v1.a = rtest_t2.a;
select * from rtest_v1;
insert into rtest_v1 select * from rtest_t3;
select * from rtest_v1;
update rtest_t1 set a = a + 10 where b > 30;
select * from rtest_v1;
-update rtest_v1 set a = rtest_t3.a + 20 where b = rtest_t3.b;
+update rtest_v1 set a = rtest_t3.a + 20 from rtest_t3 where rtest_v1.b = rtest_t3.b;
select * from rtest_v1;
--
insert into rtest_emp select * from rtest_empmass;
select ename, who = current_user as "matches user", action, newsal, oldsal from rtest_emplog order by ename, action, newsal;
update rtest_empmass set salary = salary + '1000.00';
-update rtest_emp set salary = rtest_empmass.salary where ename = rtest_empmass.ename;
+update rtest_emp set salary = rtest_empmass.salary from rtest_empmass where rtest_emp.ename = rtest_empmass.ename;
select ename, who = current_user as "matches user", action, newsal, oldsal from rtest_emplog order by ename, action, newsal;
-delete from rtest_emp where ename = rtest_empmass.ename;
+delete from rtest_emp using rtest_empmass where rtest_emp.ename = rtest_empmass.ename;
select ename, who = current_user as "matches user", action, newsal, oldsal from rtest_emplog order by ename, action, newsal;
--
-- btree index
-- awk '{if($1<10){print;}else{next;}}' onek.data | sort +0n -1
--
-SELECT onek.* WHERE onek.unique1 < 10
+SELECT * FROM onek
+ WHERE onek.unique1 < 10
ORDER BY onek.unique1;
--
-- awk '{if($1<20){print $1,$14;}else{next;}}' onek.data | sort +0nr -1
--
-SELECT onek.unique1, onek.stringu1
+SELECT onek.unique1, onek.stringu1 FROM onek
WHERE onek.unique1 < 20
ORDER BY unique1 using >;
--
-- awk '{if($1>980){print $1,$14;}else{next;}}' onek.data | sort +1d -2
--
-SELECT onek.unique1, onek.stringu1
+SELECT onek.unique1, onek.stringu1 FROM onek
WHERE onek.unique1 > 980
ORDER BY stringu1 using <;
-- awk '{if($1>980){print $1,$16;}else{next;}}' onek.data |
-- sort +1d -2 +0nr -1
--
-SELECT onek.unique1, onek.string4
+SELECT onek.unique1, onek.string4 FROM onek
WHERE onek.unique1 > 980
ORDER BY string4 using <, unique1 using >;
-- awk '{if($1>980){print $1,$16;}else{next;}}' onek.data |
-- sort +1dr -2 +0n -1
--
-SELECT onek.unique1, onek.string4
+SELECT onek.unique1, onek.string4 FROM onek
WHERE onek.unique1 > 980
ORDER BY string4 using >, unique1 using <;
-- awk '{if($1<20){print $1,$16;}else{next;}}' onek.data |
-- sort +0nr -1 +1d -2
--
-SELECT onek.unique1, onek.string4
+SELECT onek.unique1, onek.string4 FROM onek
WHERE onek.unique1 < 20
ORDER BY unique1 using >, string4 using <;
-- awk '{if($1<20){print $1,$16;}else{next;}}' onek.data |
-- sort +0n -1 +1dr -2
--
-SELECT onek.unique1, onek.string4
+SELECT onek.unique1, onek.string4 FROM onek
WHERE onek.unique1 < 20
ORDER BY unique1 using <, string4 using >;
--
-- awk '{if($1<10){print $0;}else{next;}}' onek.data | sort +0n -1
--
-SELECT onek2.* WHERE onek2.unique1 < 10;
+SELECT onek2.* FROM onek2 WHERE onek2.unique1 < 10;
--
-- awk '{if($1<20){print $1,$14;}else{next;}}' onek.data | sort +0nr -1
--
-SELECT onek2.unique1, onek2.stringu1
+SELECT onek2.unique1, onek2.stringu1 FROM onek2
WHERE onek2.unique1 < 20
ORDER BY unique1 using >;
--
-- awk '{if($1>980){print $1,$14;}else{next;}}' onek.data | sort +1d -2
--
-SELECT onek2.unique1, onek2.stringu1
+SELECT onek2.unique1, onek2.stringu1 FROM onek2
WHERE onek2.unique1 > 980;
-- test tinterval operators
-SELECT '' AS five, TINTERVAL_TBL.*;
+SELECT '' AS five, * FROM TINTERVAL_TBL;
-- length ==
SELECT '' AS one, t.*
INSERT INTO writetest VALUES (1); -- fail
SELECT * FROM writetest; -- ok
DELETE FROM temptest; -- ok
-UPDATE temptest SET a = 0 WHERE a = 1 AND writetest.a = temptest.a; -- ok
+UPDATE temptest SET a = 0 FROM writetest WHERE temptest.a = 1 AND writetest.a = temptest.a; -- ok
PREPARE test AS UPDATE writetest SET a = 0; -- ok
EXECUTE test; -- fail
SELECT * FROM writetest, temptest; -- ok
INSERT INTO VARCHAR_TBL (f1) VALUES ('c ');
-SELECT '' AS seven, VARCHAR_TBL.*;
+SELECT '' AS seven, * FROM VARCHAR_TBL;
SELECT '' AS six, c.*
FROM VARCHAR_TBL c
INSERT INTO VARCHAR_TBL (f1) VALUES ('abcde');
INSERT INTO VARCHAR_TBL (f1) VALUES ('abcd ');
-SELECT '' AS four, VARCHAR_TBL.*;
+SELECT '' AS four, * FROM VARCHAR_TBL;