From bdece235734496b551fc0b826ffd199880cee5d2 Mon Sep 17 00:00:00 2001 From: Erik Wienhold Date: Thu, 16 Oct 2025 10:30:21 +0200 Subject: [PATCH v5] doc: Apply consistent formatting to sample SQL statements Use uppercase SQL keywords consistently throughout the documentation to ease reading. Also add a single space between keywords/names and tuples which is a common convention, such as after keyword VALUES. Additional whitespace is added in a couple of other places where it improves readability. --- doc/src/sgml/advanced.sgml | 4 +- doc/src/sgml/bloom.sgml | 12 +-- doc/src/sgml/btree-gist.sgml | 8 +- doc/src/sgml/charset.sgml | 4 +- doc/src/sgml/config.sgml | 6 +- doc/src/sgml/cube.sgml | 8 +- doc/src/sgml/datatype.sgml | 18 ++-- doc/src/sgml/datetime.sgml | 6 +- doc/src/sgml/dblink.sgml | 26 +++--- doc/src/sgml/ddl.sgml | 32 ++++---- doc/src/sgml/dict-int.sgml | 2 +- doc/src/sgml/dml.sgml | 2 +- doc/src/sgml/ecpg.sgml | 10 +-- doc/src/sgml/event-trigger.sgml | 4 +- doc/src/sgml/func/func-aggregate.sgml | 4 +- doc/src/sgml/func/func-binarystring.sgml | 4 +- doc/src/sgml/func/func-bitstring.sgml | 2 +- doc/src/sgml/func/func-comparison.sgml | 4 +- doc/src/sgml/func/func-comparisons.sgml | 2 +- doc/src/sgml/func/func-json.sgml | 4 +- doc/src/sgml/func/func-matching.sgml | 8 +- doc/src/sgml/func/func-srf.sgml | 4 +- doc/src/sgml/func/func-string.sgml | 8 +- doc/src/sgml/func/func-subquery.sgml | 2 +- doc/src/sgml/func/func-xml.sgml | 20 ++--- doc/src/sgml/hstore.sgml | 8 +- doc/src/sgml/indices.sgml | 6 +- doc/src/sgml/intagg.sgml | 8 +- doc/src/sgml/isn.sgml | 12 +-- doc/src/sgml/logical-replication.sgml | 36 ++++---- doc/src/sgml/logicaldecoding.sgml | 24 +++--- doc/src/sgml/maintenance.sgml | 4 +- doc/src/sgml/manage-ag.sgml | 4 +- doc/src/sgml/monitoring.sgml | 4 +- doc/src/sgml/pgcrypto.sgml | 2 +- doc/src/sgml/pgstattuple.sgml | 2 +- doc/src/sgml/pgsurgery.sgml | 12 +-- doc/src/sgml/planstats.sgml | 2 +- doc/src/sgml/plperl.sgml | 10 +-- doc/src/sgml/plpgsql.sgml | 60 +++++++------- doc/src/sgml/plpython.sgml | 20 ++--- doc/src/sgml/pltcl.sgml | 2 +- doc/src/sgml/protocol.sgml | 12 +-- doc/src/sgml/queries.sgml | 16 ++-- doc/src/sgml/ref/alter_table.sgml | 2 +- doc/src/sgml/ref/alter_view.sgml | 4 +- doc/src/sgml/ref/create_domain.sgml | 2 +- doc/src/sgml/ref/create_function.sgml | 12 +-- doc/src/sgml/ref/create_table.sgml | 24 +++--- doc/src/sgml/ref/merge.sgml | 4 +- doc/src/sgml/ref/pg_rewind.sgml | 8 +- doc/src/sgml/ref/prepare.sgml | 2 +- doc/src/sgml/ref/psql-ref.sgml | 16 ++-- doc/src/sgml/ref/select.sgml | 18 ++-- doc/src/sgml/ref/update.sgml | 2 +- doc/src/sgml/ref/values.sgml | 6 +- doc/src/sgml/rowtypes.sgml | 6 +- doc/src/sgml/rules.sgml | 2 +- doc/src/sgml/seg.sgml | 4 +- doc/src/sgml/syntax.sgml | 14 ++-- doc/src/sgml/tablefunc.sgml | 100 +++++++++++------------ doc/src/sgml/tcn.sgml | 22 ++--- doc/src/sgml/textsearch.sgml | 12 +-- doc/src/sgml/typeconv.sgml | 6 +- doc/src/sgml/xfunc.sgml | 34 ++++---- 65 files changed, 374 insertions(+), 374 deletions(-) diff --git a/doc/src/sgml/advanced.sgml b/doc/src/sgml/advanced.sgml index e15a3323dfb..82e82c13457 100644 --- a/doc/src/sgml/advanced.sgml +++ b/doc/src/sgml/advanced.sgml @@ -101,12 +101,12 @@ SELECT * FROM myview; CREATE TABLE cities ( - name varchar(80) primary key, + name varchar(80) PRIMARY KEY, location point ); CREATE TABLE weather ( - city varchar(80) references cities(name), + city varchar(80) REFERENCES cities (name), temp_lo int, temp_hi int, prcp real, diff --git a/doc/src/sgml/bloom.sgml b/doc/src/sgml/bloom.sgml index ec5d077679b..3f6d38f377b 100644 --- a/doc/src/sgml/bloom.sgml +++ b/doc/src/sgml/bloom.sgml @@ -101,12 +101,12 @@ CREATE INDEX bloomidx ON tbloom USING bloom (i1,i2,i3) =# CREATE TABLE tbloom AS SELECT - (random() * 1000000)::int as i1, - (random() * 1000000)::int as i2, - (random() * 1000000)::int as i3, - (random() * 1000000)::int as i4, - (random() * 1000000)::int as i5, - (random() * 1000000)::int as i6 + (random() * 1000000)::int AS i1, + (random() * 1000000)::int AS i2, + (random() * 1000000)::int AS i3, + (random() * 1000000)::int AS i4, + (random() * 1000000)::int AS i5, + (random() * 1000000)::int AS i6 FROM generate_series(1,10000000); SELECT 10000000 diff --git a/doc/src/sgml/btree-gist.sgml b/doc/src/sgml/btree-gist.sgml index a4c1b99be1f..301765e7531 100644 --- a/doc/src/sgml/btree-gist.sgml +++ b/doc/src/sgml/btree-gist.sgml @@ -95,14 +95,14 @@ SELECT *, a <-> 42 AS dist FROM test ORDER BY a <-> 42 LIMIT 10; EXCLUDE USING GIST (cage WITH =, animal WITH <>) ); -=> INSERT INTO zoo VALUES(123, 'zebra'); +=> INSERT INTO zoo VALUES (123, 'zebra'); INSERT 0 1 -=> INSERT INTO zoo VALUES(123, 'zebra'); +=> INSERT INTO zoo VALUES (123, 'zebra'); INSERT 0 1 -=> INSERT INTO zoo VALUES(123, 'lion'); +=> INSERT INTO zoo VALUES (123, 'lion'); ERROR: conflicting key value violates exclusion constraint "zoo_cage_animal_excl" DETAIL: Key (cage, animal)=(123, lion) conflicts with existing key (cage, animal)=(123, zebra). -=> INSERT INTO zoo VALUES(124, 'lion'); +=> INSERT INTO zoo VALUES (124, 'lion'); INSERT 0 1 diff --git a/doc/src/sgml/charset.sgml b/doc/src/sgml/charset.sgml index 02bf4cf22b8..3aabc798012 100644 --- a/doc/src/sgml/charset.sgml +++ b/doc/src/sgml/charset.sgml @@ -570,13 +570,13 @@ CREATE COLLATION CREATE COLLATION mycollation5 (provider = icu, deterministic = false, locale = 'en-US-u-kn-ks-level2'); -SELECT 'aB' = 'Ab' COLLATE mycollation5 as result; +SELECT 'aB' = 'Ab' COLLATE mycollation5 AS result; result -------- t (1 row) -SELECT 'N-45' < 'N-123' COLLATE mycollation5 as result; +SELECT 'N-45' < 'N-123' COLLATE mycollation5 AS result; result -------- t diff --git a/doc/src/sgml/config.sgml b/doc/src/sgml/config.sgml index 06d1e4403b5..565812f7fcc 100644 --- a/doc/src/sgml/config.sgml +++ b/doc/src/sgml/config.sgml @@ -6393,9 +6393,9 @@ ANY num_sync ( SELECT 'a '::CHAR(2) COLLATE "C" < E'a\n'::CHAR(2) returns true, even though C locale would consider a space to be greater than a newline. Trailing spaces are removed when converting a character value @@ -3288,10 +3288,10 @@ CREATE TABLE holidays ( num_weeks integer, happiness happiness ); -INSERT INTO holidays(num_weeks,happiness) VALUES (4, 'happy'); -INSERT INTO holidays(num_weeks,happiness) VALUES (6, 'very happy'); -INSERT INTO holidays(num_weeks,happiness) VALUES (8, 'ecstatic'); -INSERT INTO holidays(num_weeks,happiness) VALUES (2, 'sad'); +INSERT INTO holidays (num_weeks, happiness) VALUES (4, 'happy'); +INSERT INTO holidays (num_weeks, happiness) VALUES (6, 'very happy'); +INSERT INTO holidays (num_weeks, happiness) VALUES (8, 'ecstatic'); +INSERT INTO holidays (num_weeks, happiness) VALUES (2, 'sad'); ERROR: invalid input value for enum happiness: "sad" SELECT person.name, holidays.num_weeks FROM person, holidays WHERE person.current_mood = holidays.happiness; @@ -4112,7 +4112,7 @@ SELECT macaddr8_set7bit('08:00:2b:01:02:03'); Using the Bit String Types -CREATE TABLE test (a BIT(3), b BIT VARYING(5)); +CREATE TABLE test (a bit(3), b bit varying(5)); INSERT INTO test VALUES (B'101', B'00'); INSERT INTO test VALUES (B'10', B'101'); @@ -4687,8 +4687,8 @@ SET xmloption TO { DOCUMENT | CONTENT }; CREATE DOMAIN posint AS integer CHECK (VALUE > 0); CREATE TABLE mytable (id posint); -INSERT INTO mytable VALUES(1); -- works -INSERT INTO mytable VALUES(-1); -- fails +INSERT INTO mytable VALUES (1); -- works +INSERT INTO mytable VALUES (-1); -- fails diff --git a/doc/src/sgml/datetime.sgml b/doc/src/sgml/datetime.sgml index 3e24170acbf..5905f5fa550 100644 --- a/doc/src/sgml/datetime.sgml +++ b/doc/src/sgml/datetime.sgml @@ -942,17 +942,17 @@ $ cal 9 1752 definition when you need it: do the arithmetic in time zone UTC+12. For example, -=> SELECT extract(julian from '2021-06-23 7:00:00-04'::timestamptz at time zone 'UTC+12'); +=> SELECT extract(julian FROM '2021-06-23 7:00:00-04'::timestamptz AT TIME ZONE 'UTC+12'); extract ------------------------------ 2459388.95833333333333333333 (1 row) -=> SELECT extract(julian from '2021-06-23 8:00:00-04'::timestamptz at time zone 'UTC+12'); +=> SELECT extract(julian FROM '2021-06-23 8:00:00-04'::timestamptz AT TIME ZONE 'UTC+12'); extract -------------------------------------- 2459389.0000000000000000000000000000 (1 row) -=> SELECT extract(julian from date '2021-06-23'); +=> SELECT extract(julian FROM date '2021-06-23'); extract --------- 2459389 diff --git a/doc/src/sgml/dblink.sgml b/doc/src/sgml/dblink.sgml index 808c690985b..070795992f6 100644 --- a/doc/src/sgml/dblink.sgml +++ b/doc/src/sgml/dblink.sgml @@ -444,7 +444,7 @@ dblink(text sql [, bool fail_on_error]) returns setof record The SQL query that you wish to execute in the remote database, - for example select * from foo. + for example SELECT * FROM foo. @@ -478,7 +478,7 @@ dblink(text sql [, bool fail_on_error]) returns setof record SELECT * FROM dblink('dbname=mydb options=-csearch_path=', - 'select proname, prosrc from pg_proc') + 'SELECT proname, prosrc FROM pg_proc') AS t1(proname name, prosrc text) WHERE proname LIKE 'bytea%'; @@ -513,7 +513,7 @@ SELECT * CREATE VIEW myremote_pg_proc AS SELECT * FROM dblink('dbname=postgres options=-csearch_path=', - 'select proname, prosrc from pg_proc') + 'SELECT proname, prosrc FROM pg_proc') AS t1(proname name, prosrc text); SELECT * FROM myremote_pg_proc WHERE proname LIKE 'bytea%'; @@ -525,7 +525,7 @@ SELECT * FROM myremote_pg_proc WHERE proname LIKE 'bytea%'; SELECT * FROM dblink('dbname=postgres options=-csearch_path=', - 'select proname, prosrc from pg_proc') + 'SELECT proname, prosrc FROM pg_proc') AS t1(proname name, prosrc text) WHERE proname LIKE 'bytea%'; proname | prosrc ------------+------------ @@ -549,7 +549,7 @@ SELECT dblink_connect('dbname=postgres options=-csearch_path='); OK (1 row) -SELECT * FROM dblink('select proname, prosrc from pg_proc') +SELECT * FROM dblink('SELECT proname, prosrc FROM pg_proc') AS t1(proname name, prosrc text) WHERE proname LIKE 'bytea%'; proname | prosrc ------------+------------ @@ -573,7 +573,7 @@ SELECT dblink_connect('myconn', 'dbname=regression options=-csearch_path='); OK (1 row) -SELECT * FROM dblink('myconn', 'select proname, prosrc from pg_proc') +SELECT * FROM dblink('myconn', 'SELECT proname, prosrc FROM pg_proc') AS t1(proname name, prosrc text) WHERE proname LIKE 'bytea%'; proname | prosrc ------------+------------ @@ -793,7 +793,7 @@ dblink_open(text connname, text cursorname, text sql [, bool fail_on_error]) ret The SELECT statement that you wish to execute in the remote - database, for example select * from pg_class. + database, for example SELECT * FROM pg_class. @@ -848,7 +848,7 @@ SELECT dblink_connect('dbname=postgres options=-csearch_path='); OK (1 row) -SELECT dblink_open('foo', 'select proname, prosrc from pg_proc'); +SELECT dblink_open('foo', 'SELECT proname, prosrc FROM pg_proc'); dblink_open ------------- OK @@ -969,7 +969,7 @@ SELECT dblink_connect('dbname=postgres options=-csearch_path='); OK (1 row) -SELECT dblink_open('foo', 'select proname, prosrc from pg_proc where proname like ''bytea%'''); +SELECT dblink_open('foo', 'SELECT proname, prosrc FROM pg_proc WHERE proname LIKE ''bytea%'''); dblink_open ------------- OK @@ -1106,7 +1106,7 @@ SELECT dblink_connect('dbname=postgres options=-csearch_path='); OK (1 row) -SELECT dblink_open('foo', 'select proname, prosrc from pg_proc'); +SELECT dblink_open('foo', 'SELECT proname, prosrc FROM pg_proc'); dblink_open ------------- OK @@ -1301,7 +1301,7 @@ dblink_send_query(text connname, text sql) returns int The SQL statement that you wish to execute in the remote database, - for example select * from pg_class. + for example SELECT * FROM pg_class. @@ -1583,7 +1583,7 @@ contrib_regression=# SELECT dblink_connect('dtest1', 'dbname=contrib_regression' (1 row) contrib_regression=# SELECT * FROM -contrib_regression-# dblink_send_query('dtest1', 'select * from foo where f1 < 3') AS t1; +contrib_regression-# dblink_send_query('dtest1', 'SELECT * FROM foo WHERE f1 < 3') AS t1; t1 ---- 1 @@ -1603,7 +1603,7 @@ contrib_regression=# SELECT * FROM dblink_get_result('dtest1') AS t1(f1 int, f2 (0 rows) contrib_regression=# SELECT * FROM -contrib_regression-# dblink_send_query('dtest1', 'select * from foo where f1 < 3; select * from foo where f1 > 6') AS t1; +contrib_regression-# dblink_send_query('dtest1', 'SELECT * FROM foo WHERE f1 < 3; SELECT * FROM foo WHERE f1 > 6') AS t1; t1 ---- 1 diff --git a/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml index 65bc070d2e5..50e6b900343 100644 --- a/doc/src/sgml/ddl.sgml +++ b/doc/src/sgml/ddl.sgml @@ -2834,9 +2834,9 @@ GRANT UPDATE -- admin can view all rows and fields -postgres=> set role admin; +postgres=> SET ROLE admin; SET -postgres=> table passwd; +postgres=> TABLE passwd; user_name | pwhash | uid | gid | real_name | home_phone | extra_info | home_dir | shell -----------+--------+-----+-----+-----------+--------------+------------+-------------+----------- admin | xxx | 0 | 0 | Admin | 111-222-3333 | | /root | /bin/dash @@ -2845,11 +2845,11 @@ postgres=> table passwd; (3 rows) -- Test what Alice is able to do -postgres=> set role alice; +postgres=> SET ROLE alice; SET -postgres=> table passwd; +postgres=> TABLE passwd; ERROR: permission denied for table passwd -postgres=> select user_name,real_name,home_phone,extra_info,home_dir,shell from passwd; +postgres=> SELECT user_name, real_name, home_phone, extra_info, home_dir, shell FROM passwd; user_name | real_name | home_phone | extra_info | home_dir | shell -----------+-----------+--------------+------------+-------------+----------- admin | Admin | 111-222-3333 | | /root | /bin/dash @@ -2857,21 +2857,21 @@ postgres=> select user_name,real_name,home_phone,extra_info,home_dir,shell fr alice | Alice | 098-765-4321 | | /home/alice | /bin/zsh (3 rows) -postgres=> update passwd set user_name = 'joe'; +postgres=> UPDATE passwd SET user_name = 'joe'; ERROR: permission denied for table passwd -- Alice is allowed to change her own real_name, but no others -postgres=> update passwd set real_name = 'Alice Doe'; +postgres=> UPDATE passwd SET real_name = 'Alice Doe'; UPDATE 1 -postgres=> update passwd set real_name = 'John Doe' where user_name = 'admin'; +postgres=> UPDATE passwd SET real_name = 'John Doe' WHERE user_name = 'admin'; UPDATE 0 -postgres=> update passwd set shell = '/bin/xx'; +postgres=> UPDATE passwd SET shell = '/bin/xx'; ERROR: new row violates WITH CHECK OPTION for "passwd" -postgres=> delete from passwd; +postgres=> DELETE FROM passwd; ERROR: permission denied for table passwd -postgres=> insert into passwd (user_name) values ('xxx'); +postgres=> INSERT INTO passwd (user_name) VALUES ('xxx'); ERROR: permission denied for table passwd -- Alice can change her own password; RLS silently prevents updating other rows -postgres=> update passwd set pwhash = 'abc'; +postgres=> UPDATE passwd SET pwhash = 'abc'; UPDATE 1 @@ -2904,7 +2904,7 @@ CREATE POLICY admin_local_only ON passwd AS RESTRICTIVE TO admin admin (1 row) -=> select inet_client_addr(); +=> SELECT inet_client_addr(); inet_client_addr ------------------ 127.0.0.1 @@ -2915,7 +2915,7 @@ CREATE POLICY admin_local_only ON passwd AS RESTRICTIVE TO admin -----------+--------+-----+-----+-----------+------------+------------+----------+------- (0 rows) -=> UPDATE passwd set pwhash = NULL; +=> UPDATE passwd SET pwhash = NULL; UPDATE 0 @@ -5498,7 +5498,7 @@ CREATE TYPE rainbow AS ENUM ('red', 'orange', 'yellow', CREATE TABLE my_colors (color rainbow, note text); -CREATE FUNCTION get_color_note (rainbow) RETURNS text AS +CREATE FUNCTION get_color_note(rainbow) RETURNS text AS 'SELECT note FROM my_colors WHERE color = $1' LANGUAGE SQL; @@ -5523,7 +5523,7 @@ CREATE FUNCTION get_color_note (rainbow) RETURNS text AS stored. Thus, if we write the function above as -CREATE FUNCTION get_color_note (rainbow) RETURNS text +CREATE FUNCTION get_color_note(rainbow) RETURNS text BEGIN ATOMIC SELECT note FROM my_colors WHERE color = $1; END; diff --git a/doc/src/sgml/dict-int.sgml b/doc/src/sgml/dict-int.sgml index 8dd07b9bc12..b4ce5484823 100644 --- a/doc/src/sgml/dict-int.sgml +++ b/doc/src/sgml/dict-int.sgml @@ -80,7 +80,7 @@ ALTER TEXT SEARCH DICTIONARY To test the dictionary, you can try -mydb# select ts_lexize('intdict', '12345678'); +mydb# SELECT ts_lexize('intdict', '12345678'); ts_lexize ----------- {123456} diff --git a/doc/src/sgml/dml.sgml b/doc/src/sgml/dml.sgml index 458aee788b7..61c64cf6c49 100644 --- a/doc/src/sgml/dml.sgml +++ b/doc/src/sgml/dml.sgml @@ -317,7 +317,7 @@ DELETE FROM products; column to provide unique identifiers, RETURNING can return the ID assigned to a new row: -CREATE TABLE users (firstname text, lastname text, id serial primary key); +CREATE TABLE users (firstname text, lastname text, id serial PRIMARY KEY); INSERT INTO users (firstname, lastname) VALUES ('Joe', 'Cool') RETURNING id; diff --git a/doc/src/sgml/ecpg.sgml b/doc/src/sgml/ecpg.sgml index e7a53f3c9d0..fdd35a6c3c7 100644 --- a/doc/src/sgml/ecpg.sgml +++ b/doc/src/sgml/ecpg.sgml @@ -1991,7 +1991,7 @@ EXEC SQL EXECUTE IMMEDIATE :stmt; example: EXEC SQL BEGIN DECLARE SECTION; -const char *stmt = "INSERT INTO test1 VALUES(?, ?);"; +const char *stmt = "INSERT INTO test1 VALUES (?, ?);"; EXEC SQL END DECLARE SECTION; EXEC SQL PREPARE mystmt FROM :stmt; @@ -2042,7 +2042,7 @@ EXEC SQL EXECUTE mystmt INTO :v1, :v2, :v3 USING 37; EXEC SQL BEGIN DECLARE SECTION; char dbaname[128]; char datname[128]; -char *stmt = "SELECT u.usename as dbaname, d.datname " +char *stmt = "SELECT u.usename AS dbaname, d.datname " " FROM pg_database d, pg_user u " " WHERE d.datdba = u.usesysid"; EXEC SQL END DECLARE SECTION; @@ -6685,7 +6685,7 @@ EXEC SQL CONNECT TO 'unix:postgresql://localhost/connectdb' AS main USER :user; EXEC SQL CONNECT TO :db AS :id; EXEC SQL CONNECT TO :db USER connectuser USING :pw; EXEC SQL CONNECT TO @localhost AS main USER connectdb; -EXEC SQL CONNECT TO REGRESSDB1 as main; +EXEC SQL CONNECT TO REGRESSDB1 AS main; EXEC SQL CONNECT TO AS main USER connectdb; EXEC SQL CONNECT TO connectdb AS :id; EXEC SQL CONNECT TO connectdb AS main USER connectuser/connectdb; @@ -8226,8 +8226,8 @@ main(void) $int j = 3; $CONNECT TO :dbname; -$CREATE TABLE test(i INT PRIMARY KEY, j INT); -$INSERT INTO test(i, j) VALUES (7, :j); +$CREATE TABLE test (i INT PRIMARY KEY, j INT); +$INSERT INTO test (i, j) VALUES (7, :j); $COMMIT; diff --git a/doc/src/sgml/event-trigger.sgml b/doc/src/sgml/event-trigger.sgml index 1bd9abb6676..f407a2dd2b2 100644 --- a/doc/src/sgml/event-trigger.sgml +++ b/doc/src/sgml/event-trigger.sgml @@ -388,7 +388,7 @@ CREATE EVENT TRIGGER noddl ON ddl_command_start noddl | ddl_command_start | dim | enabled | noddl | (1 row) -=# CREATE TABLE foo(id serial); +=# CREATE TABLE foo (id serial); ERROR: command "CREATE TABLE" denied @@ -433,7 +433,7 @@ $$ --- DECLARE table_oid oid := pg_event_trigger_table_rewrite_oid(); - current_hour integer := extract('hour' from current_time); + current_hour integer := extract('hour' FROM current_time); pages integer; max_pages integer := 100; BEGIN diff --git a/doc/src/sgml/func/func-aggregate.sgml b/doc/src/sgml/func/func-aggregate.sgml index f50b692516b..2ab056d439c 100644 --- a/doc/src/sgml/func/func-aggregate.sgml +++ b/doc/src/sgml/func/func-aggregate.sgml @@ -350,7 +350,7 @@ appear in the array in that order rather than in the input order. - SELECT json_arrayagg(v) FROM (VALUES(2),(1)) t(v) + SELECT json_arrayagg(v) FROM (VALUES (2), (1)) t(v) [2, 1] No @@ -1393,7 +1393,7 @@ SELECT count(*) FROM sometable; Bar | Sport | 5 (4 rows) -=> SELECT make, model, GROUPING(make,model), sum(sales) FROM items_sold GROUP BY ROLLUP(make,model); +=> SELECT make, model, GROUPING (make, model), sum(sales) FROM items_sold GROUP BY ROLLUP (make, model); make | model | grouping | sum -------+-------+----------+----- Foo | GT | 0 | 10 diff --git a/doc/src/sgml/func/func-binarystring.sgml b/doc/src/sgml/func/func-binarystring.sgml index dd7037811af..446b54010b5 100644 --- a/doc/src/sgml/func/func-binarystring.sgml +++ b/doc/src/sgml/func/func-binarystring.sgml @@ -856,8 +856,8 @@ significant byte first. Some examples: 1234::smallint::bytea \x04d2 -cast(1234 as bytea) \x000004d2 -cast(-1234 as bytea) \xfffffb2e +cast(1234 AS bytea) \x000004d2 +cast(-1234 AS bytea) \xfffffb2e '\x8000'::bytea::smallint -32768 '\x8000'::bytea::integer 32768 diff --git a/doc/src/sgml/func/func-bitstring.sgml b/doc/src/sgml/func/func-bitstring.sgml index f03dd63afcc..c73efc6b7c6 100644 --- a/doc/src/sgml/func/func-bitstring.sgml +++ b/doc/src/sgml/func/func-bitstring.sgml @@ -348,7 +348,7 @@ 44::bit(10) 0000101100 44::bit(3) 100 -cast(-44 as bit(12)) 111111010100 +cast(-44 AS bit(12)) 111111010100 '1110'::bit(4)::integer 14 Note that casting to just bit means casting to diff --git a/doc/src/sgml/func/func-comparison.sgml b/doc/src/sgml/func/func-comparison.sgml index ecb1d89463a..a41ebe3b709 100644 --- a/doc/src/sgml/func/func-comparison.sgml +++ b/doc/src/sgml/func/func-comparison.sgml @@ -523,13 +523,13 @@ for both tests. For example: -SELECT ROW(1,2.5,'this is a test') = ROW(1, 3, 'not the same'); +SELECT ROW(1, 2.5, 'this is a test') = ROW(1, 3, 'not the same'); SELECT ROW(table.*) IS NULL FROM table; -- detect all-null rows SELECT ROW(table.*) IS NOT NULL FROM table; -- detect all-non-null rows -SELECT NOT(ROW(table.*) IS NOT NULL) FROM TABLE; -- detect at least one null in rows +SELECT NOT (ROW(table.*) IS NOT NULL) FROM TABLE; -- detect at least one null in rows In some cases, it may be preferable to diff --git a/doc/src/sgml/func/func-comparisons.sgml b/doc/src/sgml/func/func-comparisons.sgml index 6a6e0bd4019..e2cdada5e79 100644 --- a/doc/src/sgml/func/func-comparisons.sgml +++ b/doc/src/sgml/func/func-comparisons.sgml @@ -244,7 +244,7 @@ AND If either of this pair of elements is null, the result of the row comparison is unknown (null); otherwise comparison of this pair of elements determines the result. For example, - ROW(1,2,NULL) < ROW(1,3,0) + ROW(1, 2, NULL) < ROW(1, 3, 0) yields true, not null, because the third pair of elements are not considered. diff --git a/doc/src/sgml/func/func-json.sgml b/doc/src/sgml/func/func-json.sgml index b9316ba0ee5..8d6a65083da 100644 --- a/doc/src/sgml/func/func-json.sgml +++ b/doc/src/sgml/func/func-json.sgml @@ -627,7 +627,7 @@ [1, true, {"a":null}] - json_array(SELECT * FROM (VALUES(1),(2)) t) + json_array(SELECT * FROM (VALUES (1), (2)) t) [1, 2] @@ -3423,7 +3423,7 @@ DETAIL: Missing "]" after array dimensions. 2015-02-01 - JSON_VALUE(jsonb '[1,2]', 'strict $[$off]' PASSING 1 as off) + JSON_VALUE(jsonb '[1,2]', 'strict $[$off]' PASSING 1 AS off) 2 diff --git a/doc/src/sgml/func/func-matching.sgml b/doc/src/sgml/func/func-matching.sgml index ebe0b22c8f6..91a0b7ca0de 100644 --- a/doc/src/sgml/func/func-matching.sgml +++ b/doc/src/sgml/func/func-matching.sgml @@ -412,8 +412,8 @@ substring(string, pattern, Some examples, with #" delimiting the return string: -substring('foobar' similar '%#"o_b#"%' escape '#') oob -substring('foobar' similar '#"o_b#"%' escape '#') NULL +substring('foobar' SIMILAR '%#"o_b#"%' ESCAPE '#') oob +substring('foobar' SIMILAR '#"o_b#"%' ESCAPE '#') NULL @@ -600,8 +600,8 @@ substring('foobar' similar '#"o_b#"%' escape '#') NULL Some examples: -substring('foobar' from 'o.b') oob -substring('foobar' from 'o(.)b') o +substring('foobar' FROM 'o.b') oob +substring('foobar' FROM 'o(.)b') o diff --git a/doc/src/sgml/func/func-srf.sgml b/doc/src/sgml/func/func-srf.sgml index eafc961c9f9..34a45971aad 100644 --- a/doc/src/sgml/func/func-srf.sgml +++ b/doc/src/sgml/func/func-srf.sgml @@ -247,8 +247,8 @@ FROM (SELECT generate_subscripts(a, 1) AS s, a FROM arrays) foo; -- unnest a 2D array: CREATE OR REPLACE FUNCTION unnest2(anyarray) RETURNS SETOF anyelement AS $$ -select $1[i][j] - from generate_subscripts($1,1) g1(i), +SELECT $1[i][j] + FROM generate_subscripts($1,1) g1(i), generate_subscripts($1,2) g2(j); $$ LANGUAGE sql IMMUTABLE; CREATE FUNCTION diff --git a/doc/src/sgml/func/func-string.sgml b/doc/src/sgml/func/func-string.sgml index 01cc94c234e..449ad85a60e 100644 --- a/doc/src/sgml/func/func-string.sgml +++ b/doc/src/sgml/func/func-string.sgml @@ -1752,11 +1752,11 @@ SELECT format('Hello %s', 'World'); SELECT format('Testing %s, %s, %s, %%', 'one', 'two', 'three'); Result: Testing one, two, three, % -SELECT format('INSERT INTO %I VALUES(%L)', 'Foo bar', E'O\'Reilly'); -Result: INSERT INTO "Foo bar" VALUES('O''Reilly') +SELECT format('INSERT INTO %I VALUES (%L)', 'Foo bar', E'O\'Reilly'); +Result: INSERT INTO "Foo bar" VALUES ('O''Reilly') -SELECT format('INSERT INTO %I VALUES(%L)', 'locations', 'C:\Program Files'); -Result: INSERT INTO locations VALUES('C:\Program Files') +SELECT format('INSERT INTO %I VALUES (%L)', 'locations', 'C:\Program Files'); +Result: INSERT INTO locations VALUES ('C:\Program Files') diff --git a/doc/src/sgml/func/func-subquery.sgml b/doc/src/sgml/func/func-subquery.sgml index a9f2b12e48c..314c82ee1de 100644 --- a/doc/src/sgml/func/func-subquery.sgml +++ b/doc/src/sgml/func/func-subquery.sgml @@ -70,7 +70,7 @@ EXISTS (subquery) and not on the contents of those rows, the output list of the subquery is normally unimportant. A common coding convention is to write all EXISTS tests in the form - EXISTS(SELECT 1 WHERE ...). There are exceptions to + EXISTS (SELECT 1 WHERE ...). There are exceptions to this rule however, such as subqueries that use INTERSECT. diff --git a/doc/src/sgml/func/func-xml.sgml b/doc/src/sgml/func/func-xml.sgml index 21f34467a4f..511bc90852a 100644 --- a/doc/src/sgml/func/func-xml.sgml +++ b/doc/src/sgml/func/func-xml.sgml @@ -177,19 +177,19 @@ SELECT xmlconcat('', ' Examples: -SELECT xmlelement(name foo, xmlattributes('xyz' as bar)); +SELECT xmlelement(NAME foo, xmlattributes('xyz' AS bar)); xmlelement ------------------ -SELECT xmlelement(name foo, xmlattributes(current_date as bar), 'cont', 'ent'); +SELECT xmlelement(NAME foo, xmlattributes(current_date AS bar), 'cont', 'ent'); xmlelement ------------------------------------- @@ -204,7 +204,7 @@ SELECT xmlelement(name foo, xmlattributes(current_date as bar), 'cont', 'ent'); HHHH is the character's Unicode codepoint in hexadecimal notation. For example: CREATE TABLE test (a xml, b xml); -SELECT xmlelement(name test, xmlattributes(a, b)) FROM test; +SELECT xmlelement(NAME test, xmlattributes(a, b)) FROM test; But these are not: -SELECT xmlelement(name test, xmlattributes('constant'), a, b) FROM test; -SELECT xmlelement(name test, xmlattributes(func(a, b))) FROM test; +SELECT xmlelement(NAME test, xmlattributes('constant'), a, b) FROM test; +SELECT xmlelement(NAME test, xmlattributes(func(a, b))) FROM test; @@ -234,10 +234,10 @@ SELECT xmlelement(name test, xmlattributes(func(a, b))) FROM test; its data type. If the content is itself of type xml, complex XML documents can be constructed. For example: hstore. - ROW(1,3) #= 'f1=>11'::hstore + ROW(1, 3) #= 'f1=>11'::hstore (11,3) @@ -346,7 +346,7 @@ key => NULL Constructs an hstore from a record or row. - hstore(ROW(1,2)) + hstore(ROW(1, 2)) "f1"=>"1", "f2"=>"2" @@ -696,7 +696,7 @@ b with matching values from hstore. - populate_record(ROW(1,2), 'f1=>42'::hstore) + populate_record(ROW(1, 2), 'f1=>42'::hstore) (42,2) @@ -799,7 +799,7 @@ UPDATE tab SET h = h || hstore('c', '3'); If multiple keys are to be added or changed in one operation, the concatenation approach is more efficient than subscripting: -UPDATE tab SET h = h || hstore(array['q', 'w'], array['11', '12']); +UPDATE tab SET h = h || hstore(ARRAY['q', 'w'], ARRAY['11', '12']); diff --git a/doc/src/sgml/indices.sgml b/doc/src/sgml/indices.sgml index 9c4f76abf0d..6469f032f23 100644 --- a/doc/src/sgml/indices.sgml +++ b/doc/src/sgml/indices.sgml @@ -949,19 +949,19 @@ WHERE url = '/index.html' AND client_ip = inet '192.168.100.23'; command to create the index would look like this: CREATE INDEX orders_unbilled_index ON orders (order_nr) - WHERE billed is not true; + WHERE billed IS NOT TRUE; A possible query to use this index would be: -SELECT * FROM orders WHERE billed is not true AND order_nr < 10000; +SELECT * FROM orders WHERE billed IS NOT TRUE AND order_nr < 10000; However, the index can also be used in queries that do not involve order_nr at all, e.g.: -SELECT * FROM orders WHERE billed is not true AND amount > 5000.00; +SELECT * FROM orders WHERE billed IS NOT TRUE AND amount > 5000.00; This is not as efficient as a partial index on the amount column would be, since the system has to diff --git a/doc/src/sgml/intagg.sgml b/doc/src/sgml/intagg.sgml index 29e74ce146c..924fcdcd75a 100644 --- a/doc/src/sgml/intagg.sgml +++ b/doc/src/sgml/intagg.sgml @@ -58,10 +58,10 @@ usually sits between two indexed tables, for example: -CREATE TABLE left_table (id INT PRIMARY KEY, ...); -CREATE TABLE right_table (id INT PRIMARY KEY, ...); -CREATE TABLE many_to_many(id_left INT REFERENCES left_table, - id_right INT REFERENCES right_table); +CREATE TABLE left_table (id INT PRIMARY KEY, ...); +CREATE TABLE right_table (id INT PRIMARY KEY, ...); +CREATE TABLE many_to_many (id_left INT REFERENCES left_table, + id_right INT REFERENCES right_table); It is typically used like this: diff --git a/doc/src/sgml/isn.sgml b/doc/src/sgml/isn.sgml index 1f08ada6218..857482a19b4 100644 --- a/doc/src/sgml/isn.sgml +++ b/doc/src/sgml/isn.sgml @@ -379,20 +379,20 @@ SELECT ean13(upc('220356483481')); --Create a table with a single column to hold ISBN numbers: CREATE TABLE test (id isbn); -INSERT INTO test VALUES('9780393040029'); +INSERT INTO test VALUES ('9780393040029'); --Automatically calculate check digits (observe the '?'): -INSERT INTO test VALUES('220500896?'); -INSERT INTO test VALUES('978055215372?'); +INSERT INTO test VALUES ('220500896?'); +INSERT INTO test VALUES ('978055215372?'); SELECT issn('3251231?'); SELECT ismn('979047213542?'); --Using the weak mode: SET isn.weak TO true; -INSERT INTO test VALUES('978-0-11-000533-4'); -INSERT INTO test VALUES('9780141219307'); -INSERT INTO test VALUES('2-205-00876-X'); +INSERT INTO test VALUES ('978-0-11-000533-4'); +INSERT INTO test VALUES ('9780141219307'); +INSERT INTO test VALUES ('2-205-00876-X'); SET isn.weak TO false; SELECT id FROM test WHERE NOT is_valid(id); diff --git a/doc/src/sgml/logical-replication.sgml b/doc/src/sgml/logical-replication.sgml index b01f5e998b2..ab3b6f8d792 100644 --- a/doc/src/sgml/logical-replication.sgml +++ b/doc/src/sgml/logical-replication.sgml @@ -365,17 +365,17 @@ Create some test tables on the publisher. -/* pub # */ CREATE TABLE t1(a int, b text, PRIMARY KEY(a)); -/* pub # */ CREATE TABLE t2(c int, d text, PRIMARY KEY(c)); -/* pub # */ CREATE TABLE t3(e int, f text, PRIMARY KEY(e)); +/* pub # */ CREATE TABLE t1 (a int, b text, PRIMARY KEY (a)); +/* pub # */ CREATE TABLE t2 (c int, d text, PRIMARY KEY (c)); +/* pub # */ CREATE TABLE t3 (e int, f text, PRIMARY KEY (e)); Create the same tables on the subscriber. -/* sub # */ CREATE TABLE t1(a int, b text, PRIMARY KEY(a)); -/* sub # */ CREATE TABLE t2(c int, d text, PRIMARY KEY(c)); -/* sub # */ CREATE TABLE t3(e int, f text, PRIMARY KEY(e)); +/* sub # */ CREATE TABLE t1 (a int, b text, PRIMARY KEY (a)); +/* sub # */ CREATE TABLE t2 (c int, d text, PRIMARY KEY (c)); +/* sub # */ CREATE TABLE t3 (e int, f text, PRIMARY KEY (e)); @@ -1028,9 +1028,9 @@ HINT: To initiate replication, you must manually create the replication slot, e Create some tables to be used in the following examples. -/* pub # */ CREATE TABLE t1(a int, b int, c text, PRIMARY KEY(a,c)); -/* pub # */ CREATE TABLE t2(d int, e int, f int, PRIMARY KEY(d)); -/* pub # */ CREATE TABLE t3(g int, h int, i int, PRIMARY KEY(g)); +/* pub # */ CREATE TABLE t1 (a int, b int, c text, PRIMARY KEY (a, c)); +/* pub # */ CREATE TABLE t2 (d int, e int, f int, PRIMARY KEY (d)); +/* pub # */ CREATE TABLE t3 (g int, h int, i int, PRIMARY KEY (g)); @@ -1125,7 +1125,7 @@ Publications: definition as the one on the publisher, and also create the subscription s1 that subscribes to the publication p1. -/* sub # */ CREATE TABLE t1(a int, b int, c text, PRIMARY KEY(a,c)); +/* sub # */ CREATE TABLE t1 (a int, b int, c text, PRIMARY KEY (a, c)); /* sub # */ CREATE SUBSCRIPTION s1 /* sub - */ CONNECTION 'host=localhost dbname=test_pub application_name=s1' /* sub - */ PUBLICATION p1; @@ -1269,12 +1269,12 @@ Publications: Create a partitioned table on the publisher. -/* pub # */ CREATE TABLE parent(a int PRIMARY KEY) PARTITION BY RANGE(a); +/* pub # */ CREATE TABLE parent (a int PRIMARY KEY) PARTITION BY RANGE (a); /* pub # */ CREATE TABLE child PARTITION OF parent DEFAULT; Create the same tables on the subscriber. -/* sub # */ CREATE TABLE parent(a int PRIMARY KEY) PARTITION BY RANGE(a); +/* sub # */ CREATE TABLE parent (a int PRIMARY KEY) PARTITION BY RANGE (a); /* sub # */ CREATE TABLE child PARTITION OF parent DEFAULT; @@ -1476,7 +1476,7 @@ Publications: Create a table t1 to be used in the following example. -/* pub # */ CREATE TABLE t1(id int, a text, b text, c text, d text, e text, PRIMARY KEY(id)); +/* pub # */ CREATE TABLE t1 (id int, a text, b text, c text, d text, e text, PRIMARY KEY (id)); @@ -1528,7 +1528,7 @@ Publications: s1 that subscribes to the publication p1. -/* sub # */ CREATE TABLE t1(id int, b text, a text, d text, PRIMARY KEY(id)); +/* sub # */ CREATE TABLE t1 (id int, b text, a text, d text, PRIMARY KEY (id)); /* sub # */ CREATE SUBSCRIPTION s1 /* sub - */ CONNECTION 'host=localhost dbname=test_pub application_name=s1' /* sub - */ PUBLICATION p1; @@ -1537,9 +1537,9 @@ Publications: On the publisher node, insert some rows to table t1. -/* pub # */ INSERT INTO t1 VALUES(1, 'a-1', 'b-1', 'c-1', 'd-1', 'e-1'); -/* pub # */ INSERT INTO t1 VALUES(2, 'a-2', 'b-2', 'c-2', 'd-2', 'e-2'); -/* pub # */ INSERT INTO t1 VALUES(3, 'a-3', 'b-3', 'c-3', 'd-3', 'e-3'); +/* pub # */ INSERT INTO t1 VALUES (1, 'a-1', 'b-1', 'c-1', 'd-1', 'e-1'); +/* pub # */ INSERT INTO t1 VALUES (2, 'a-2', 'b-2', 'c-2', 'd-2', 'e-2'); +/* pub # */ INSERT INTO t1 VALUES (3, 'a-3', 'b-3', 'c-3', 'd-3', 'e-3'); /* pub # */ SELECT * FROM t1 ORDER BY id; id | a | b | c | d | e ----+-----+-----+-----+-----+----- @@ -1594,7 +1594,7 @@ Publications: /* sub # */ CREATE TABLE tab_gen_to_gen (a int, b int GENERATED ALWAYS AS (a * 100) STORED); /* sub # */ CREATE SUBSCRIPTION sub1 CONNECTION 'dbname=test_pub' PUBLICATION pub1; -/* sub # */ SELECT * from tab_gen_to_gen; +/* sub # */ SELECT * FROM tab_gen_to_gen; a | b ---+---- 1 | 100 diff --git a/doc/src/sgml/logicaldecoding.sgml b/doc/src/sgml/logicaldecoding.sgml index b803a819cf1..2a327ac0b92 100644 --- a/doc/src/sgml/logicaldecoding.sgml +++ b/doc/src/sgml/logicaldecoding.sgml @@ -73,7 +73,7 @@ postgres=# SELECT * FROM pg_logical_slot_get_changes('regression_slot', NULL, NU -----+-----+------ (0 rows) -postgres=# CREATE TABLE data(id serial primary key, data text); +postgres=# CREATE TABLE data (id serial PRIMARY KEY, data text); CREATE TABLE postgres=# -- DDL isn't replicated, so all you'll see is the transaction @@ -92,8 +92,8 @@ postgres=# SELECT * FROM pg_logical_slot_get_changes('regression_slot', NULL, NU (0 rows) postgres=# BEGIN; -postgres=*# INSERT INTO data(data) VALUES('1'); -postgres=*# INSERT INTO data(data) VALUES('2'); +postgres=*# INSERT INTO data (data) VALUES ('1'); +postgres=*# INSERT INTO data (data) VALUES ('2'); postgres=*# COMMIT; postgres=# SELECT * FROM pg_logical_slot_get_changes('regression_slot', NULL, NULL); @@ -105,7 +105,7 @@ postgres=# SELECT * FROM pg_logical_slot_get_changes('regression_slot', NULL, NU 0/0BA5A8A8 | 10298 | COMMIT 10298 (4 rows) -postgres=# INSERT INTO data(data) VALUES('3'); +postgres=# INSERT INTO data (data) VALUES ('3'); postgres=# -- You can also peek ahead in the change stream without consuming changes postgres=# SELECT * FROM pg_logical_slot_peek_changes('regression_slot', NULL, NULL); @@ -160,7 +160,7 @@ Example 1: $ pg_recvlogical -d postgres --slot=test --create-slot $ pg_recvlogical -d postgres --slot=test --start -f - ControlZ -$ psql -d postgres -c "INSERT INTO data(data) VALUES('4');" +$ psql -d postgres -c "INSERT INTO data (data) VALUES ('4');" $ fg BEGIN 693 table public.data: INSERT: id[integer]:4 data[text]:'4' @@ -172,7 +172,7 @@ Example 2: $ pg_recvlogical -d postgres --slot=test --create-slot --enable-two-phase $ pg_recvlogical -d postgres --slot=test --start -f - ControlZ -$ psql -d postgres -c "BEGIN;INSERT INTO data(data) VALUES('5');PREPARE TRANSACTION 'test';" +$ psql -d postgres -c "BEGIN; INSERT INTO data (data) VALUES ('5'); PREPARE TRANSACTION 'test';" $ fg BEGIN 694 table public.data: INSERT: id[integer]:5 data[text]:'5' @@ -196,7 +196,7 @@ $ pg_recvlogical -d postgres --slot=test --drop-slot postgres=# BEGIN; -postgres=*# INSERT INTO data(data) VALUES('5'); +postgres=*# INSERT INTO data (data) VALUES ('5'); postgres=*# PREPARE TRANSACTION 'test_prepared1'; postgres=# SELECT * FROM pg_logical_slot_get_changes('regression_slot', NULL, NULL); @@ -208,7 +208,7 @@ postgres=# SELECT * FROM pg_logical_slot_get_changes('regression_slot', NULL, NU (3 rows) postgres=# COMMIT PREPARED 'test_prepared1'; -postgres=# select * from pg_logical_slot_get_changes('regression_slot', NULL, NULL); +postgres=# SELECT * from pg_logical_slot_get_changes('regression_slot', NULL, NULL); lsn | xid | data ------------+-----+-------------------------------------------- 0/0168A060 | 529 | COMMIT PREPARED 'test_prepared1', txid 529 @@ -216,9 +216,9 @@ postgres=# select * from pg_logical_slot_get_changes('regression_slot', NULL, NU postgres=#-- you can also rollback a prepared transaction postgres=# BEGIN; -postgres=*# INSERT INTO data(data) VALUES('6'); +postgres=*# INSERT INTO data (data) VALUES ('6'); postgres=*# PREPARE TRANSACTION 'test_prepared2'; -postgres=# select * from pg_logical_slot_get_changes('regression_slot', NULL, NULL); +postgres=# SELECT * from pg_logical_slot_get_changes('regression_slot', NULL, NULL); lsn | xid | data ------------+-----+--------------------------------------------------------- 0/0168A180 | 530 | BEGIN 530 @@ -227,7 +227,7 @@ postgres=# select * from pg_logical_slot_get_changes('regression_slot', NULL, NU (3 rows) postgres=# ROLLBACK PREPARED 'test_prepared2'; -postgres=# select * from pg_logical_slot_get_changes('regression_slot', NULL, NULL); +postgres=# SELECT * from pg_logical_slot_get_changes('regression_slot', NULL, NULL); lsn | xid | data ------------+-----+---------------------------------------------- 0/0168A4B8 | 530 | ROLLBACK PREPARED 'test_prepared2', txid 530 @@ -830,7 +830,7 @@ typedef void (*LogicalOutputPluginInit) (struct OutputPluginCallbacks *cb); provided catalog tables using ALTER TABLE user_catalog_table SET (user_catalog_table = true); -CREATE TABLE another_catalog_table(data text) WITH (user_catalog_table = true); +CREATE TABLE another_catalog_table (data text) WITH (user_catalog_table = true); Note that access to user catalog tables or regular system catalog tables in the output plugins has to be done via the systable_* diff --git a/doc/src/sgml/maintenance.sgml b/doc/src/sgml/maintenance.sgml index dc59c88319e..120bac8875f 100644 --- a/doc/src/sgml/maintenance.sgml +++ b/doc/src/sgml/maintenance.sgml @@ -614,8 +614,8 @@ examine this information is to execute queries such as: -SELECT c.oid::regclass as table_name, - greatest(age(c.relfrozenxid),age(t.relfrozenxid)) as age +SELECT c.oid::regclass AS table_name, + greatest(age(c.relfrozenxid), age(t.relfrozenxid)) AS age FROM pg_class c LEFT JOIN pg_class t ON c.reltoastrelid = t.oid WHERE c.relkind IN ('r', 'm'); diff --git a/doc/src/sgml/manage-ag.sgml b/doc/src/sgml/manage-ag.sgml index fe4cb4410cd..bb9efb97ceb 100644 --- a/doc/src/sgml/manage-ag.sgml +++ b/doc/src/sgml/manage-ag.sgml @@ -464,7 +464,7 @@ CREATE TABLESPACE fastspace LOCATION '/ssd1/postgresql/data'; parameter to the relevant command. For example, the following creates a table in the tablespace space1: -CREATE TABLE foo(i int) TABLESPACE space1; +CREATE TABLE foo (i int) TABLESPACE space1; @@ -472,7 +472,7 @@ CREATE TABLE foo(i int) TABLESPACE space1; Alternatively, use the parameter: SET default_tablespace = space1; -CREATE TABLE foo(i int); +CREATE TABLE foo (i int); When default_tablespace is set to anything but an empty string, it supplies an implicit TABLESPACE clause for diff --git a/doc/src/sgml/monitoring.sgml b/doc/src/sgml/monitoring.sgml index f3bf527d5b4..fc64df43e3f 100644 --- a/doc/src/sgml/monitoring.sgml +++ b/doc/src/sgml/monitoring.sgml @@ -1137,7 +1137,7 @@ postgres 27093 0.0 0.0 30096 2752 ? Ss 11:34 0:00 postgres: ser Here are examples of how wait events can be viewed: -SELECT pid, wait_event_type, wait_event FROM pg_stat_activity WHERE wait_event is NOT NULL; +SELECT pid, wait_event_type, wait_event FROM pg_stat_activity WHERE wait_event IS NOT NULL; pid | wait_event_type | wait_event ------+-----------------+------------ 2540 | Lock | relation @@ -1150,7 +1150,7 @@ SELECT a.pid, a.wait_event, w.description FROM pg_stat_activity a JOIN pg_wait_events w ON (a.wait_event_type = w.type AND a.wait_event = w.name) - WHERE a.wait_event is NOT NULL and a.state = 'active'; + WHERE a.wait_event IS NOT NULL AND a.state = 'active'; -[ RECORD 1 ]------------------------------------------------------&zwsp;------------ pid | 686674 wait_event | WALInitSync diff --git a/doc/src/sgml/pgcrypto.sgml b/doc/src/sgml/pgcrypto.sgml index bc5c74ad017..6fc2069ad3e 100644 --- a/doc/src/sgml/pgcrypto.sgml +++ b/doc/src/sgml/pgcrypto.sgml @@ -57,7 +57,7 @@ digest(data bytea, type text) returns bytea If you want the digest as a hexadecimal string, use encode() on the result. For example: -CREATE OR REPLACE FUNCTION sha1(bytea) returns text AS $$ +CREATE OR REPLACE FUNCTION sha1(bytea) RETURNS text AS $$ SELECT encode(digest($1, 'sha1'), 'hex') $$ LANGUAGE SQL STRICT IMMUTABLE; diff --git a/doc/src/sgml/pgstattuple.sgml b/doc/src/sgml/pgstattuple.sgml index c747a5818ab..54d8f90245e 100644 --- a/doc/src/sgml/pgstattuple.sgml +++ b/doc/src/sgml/pgstattuple.sgml @@ -377,7 +377,7 @@ pending_tuples | 0 pgstathashindex returns a record showing information about a HASH index. For example: -test=> select * from pgstathashindex('con_hash_index'); +test=> SELECT * FROM pgstathashindex('con_hash_index'); -[ RECORD 1 ]--+----------------- version | 4 bucket_pages | 33081 diff --git a/doc/src/sgml/pgsurgery.sgml b/doc/src/sgml/pgsurgery.sgml index 29bccd7f36d..68186122a22 100644 --- a/doc/src/sgml/pgsurgery.sgml +++ b/doc/src/sgml/pgsurgery.sgml @@ -34,17 +34,17 @@ intended use of this function is to forcibly remove tuples that are not otherwise accessible. For example: -test=> select * from t1 where ctid = '(0, 1)'; +test=> SELECT * FROM t1 WHERE ctid = '(0, 1)'; ERROR: could not access status of transaction 4007513275 DETAIL: Could not open file "pg_xact/0EED": No such file or directory. -test=# select heap_force_kill('t1'::regclass, ARRAY['(0, 1)']::tid[]); +test=# SELECT heap_force_kill('t1'::regclass, ARRAY['(0, 1)']::tid[]); heap_force_kill ----------------- (1 row) -test=# select * from t1 where ctid = '(0, 1)'; +test=# SELECT * FROM t1 WHERE ctid = '(0, 1)'; (0 rows) @@ -70,19 +70,19 @@ test=> vacuum t1; ERROR: found xmin 507 from before relfrozenxid 515 CONTEXT: while scanning block 0 of relation "public.t1" -test=# select ctid from t1 where xmin = 507; +test=# SELECT ctid FROM t1 WHERE xmin = 507; ctid ------- (0,3) (1 row) -test=# select heap_force_freeze('t1'::regclass, ARRAY['(0, 3)']::tid[]); +test=# SELECT heap_force_freeze('t1'::regclass, ARRAY['(0, 3)']::tid[]); heap_force_freeze ------------------- (1 row) -test=# select ctid from t1 where xmin = 2; +test=# SELECT ctid FROM t1 WHERE xmin = 2; ctid ------- (0,3) diff --git a/doc/src/sgml/planstats.sgml b/doc/src/sgml/planstats.sgml index 068b804a18d..e57867ba617 100644 --- a/doc/src/sgml/planstats.sgml +++ b/doc/src/sgml/planstats.sgml @@ -635,7 +635,7 @@ EXPLAIN (ANALYZE, TIMING OFF, BUFFERS OFF) SELECT * FROM t WHERE a = 1 AND b = 1 pg_mcv_list_items set-returning function. -SELECT m.* FROM pg_statistic_ext join pg_statistic_ext_data on (oid = stxoid), +SELECT m.* FROM pg_statistic_ext JOIN pg_statistic_ext_data ON (oid = stxoid), pg_mcv_list_items(stxdmcv) m WHERE stxname = 'stts2'; index | values | nulls | frequency | base_frequency -------+----------+-------+-----------+---------------- diff --git a/doc/src/sgml/plperl.sgml b/doc/src/sgml/plperl.sgml index 8007261d022..04bfa5719c9 100644 --- a/doc/src/sgml/plperl.sgml +++ b/doc/src/sgml/plperl.sgml @@ -125,7 +125,7 @@ $$ LANGUAGE plperl; could be defined as: -CREATE FUNCTION perl_max (integer, integer) RETURNS integer AS $$ +CREATE FUNCTION perl_max(integer, integer) RETURNS integer AS $$ if ($_[0] > $_[1]) { return $_[0]; } return $_[1]; $$ LANGUAGE plperl; @@ -156,7 +156,7 @@ $$ LANGUAGE plperl; rather than a null value: -CREATE FUNCTION perl_max (integer, integer) RETURNS integer AS $$ +CREATE FUNCTION perl_max(integer, integer) RETURNS integer AS $$ my ($x, $y) = @_; if (not defined $x) { return undef if not defined $y; @@ -229,7 +229,7 @@ $$ LANGUAGE plperl; references to Perl arrays. Here is an example: -CREATE OR REPLACE function returns_array() +CREATE OR REPLACE FUNCTION returns_array() RETURNS text[][] AS $$ return [['a"b','c,d'],['e\\f','g']]; $$ LANGUAGE plperl; @@ -565,7 +565,7 @@ SELECT * FROM test_munge(); CREATE TYPE foo_type AS (the_num INTEGER, the_text TEXT); -CREATE OR REPLACE FUNCTION lotsa_md5 (INTEGER) RETURNS SETOF foo_type AS $$ +CREATE OR REPLACE FUNCTION lotsa_md5(INTEGER) RETURNS SETOF foo_type AS $$ use Digest::MD5 qw(md5_hex); my $file = '/usr/share/dict/words'; my $t = localtime; @@ -588,7 +588,7 @@ CREATE OR REPLACE FUNCTION lotsa_md5 (INTEGER) RETURNS SETOF foo_type AS $$ return; $$ LANGUAGE plperlu; -SELECT * from lotsa_md5(500); +SELECT * FROM lotsa_md5(500); diff --git a/doc/src/sgml/plpgsql.sgml b/doc/src/sgml/plpgsql.sgml index e937491e6b8..560ed963174 100644 --- a/doc/src/sgml/plpgsql.sgml +++ b/doc/src/sgml/plpgsql.sgml @@ -555,7 +555,7 @@ CALL sum_n_product(2, 4, NULL, NULL); CREATE FUNCTION extended_sales(p_itemno int) -RETURNS TABLE(quantity int, total numeric) AS $$ +RETURNS TABLE (quantity int, total numeric) AS $$ BEGIN RETURN QUERY SELECT s.quantity, s.quantity * s.price FROM sales AS s WHERE s.itemno = p_itemno; @@ -1023,7 +1023,7 @@ IF count(*) > 0 FROM my_table THEN ... tax := subtotal * 0.06; my_record.user_id := 20; my_array[j] := 20; -my_array[1:3] := array[1,2,3]; +my_array[1:3] := ARRAY[1, 2, 3]; complex_array[n].realpart = 12.3; @@ -1037,8 +1037,8 @@ complex_array[n].realpart = 12.3; within a PL/pgSQL function just by writing the command. For example, you could create and fill a table by writing -CREATE TABLE mytable (id int primary key, data text); -INSERT INTO mytable VALUES (1,'one'), (2,'two'); +CREATE TABLE mytable (id int PRIMARY KEY, data text); +INSERT INTO mytable VALUES (1, 'one'), (2, 'two'); @@ -2861,7 +2861,7 @@ WHEN SQLSTATE '22012' THEN ... As an example, consider this fragment: -INSERT INTO mytab(firstname, lastname) VALUES('Tom', 'Jones'); +INSERT INTO mytab (firstname, lastname) VALUES ('Tom', 'Jones'); BEGIN UPDATE mytab SET firstname = 'Joe' WHERE lastname = 'Jones'; x := x + 1; @@ -2905,7 +2905,7 @@ END; CREATE TABLE db (a INT PRIMARY KEY, b TEXT); -CREATE FUNCTION merge_db(key INT, data TEXT) RETURNS VOID AS +CREATE FUNCTION merge_db(key INT, data TEXT) RETURNS void AS $$ BEGIN LOOP @@ -2918,7 +2918,7 @@ BEGIN -- if someone else inserts the same key concurrently, -- we could get a unique-key failure BEGIN - INSERT INTO db(a,b) VALUES (key, data); + INSERT INTO db (a, b) VALUES (key, data); RETURN; EXCEPTION WHEN unique_violation THEN -- Do nothing, and loop to try the UPDATE again. @@ -4381,7 +4381,7 @@ CREATE TABLE emp ( salary integer ); -CREATE TABLE emp_audit( +CREATE TABLE emp_audit ( operation char(1) NOT NULL, stamp timestamp NOT NULL, userid text NOT NULL, @@ -4439,7 +4439,7 @@ CREATE TABLE emp ( salary integer ); -CREATE TABLE emp_audit( +CREATE TABLE emp_audit ( operation char(1) NOT NULL, userid text NOT NULL, empname text NOT NULL, @@ -4466,20 +4466,20 @@ CREATE OR REPLACE FUNCTION update_emp_view() RETURNS TRIGGER AS $$ IF NOT FOUND THEN RETURN NULL; END IF; OLD.last_updated = now(); - INSERT INTO emp_audit VALUES('D', current_user, OLD.*); + INSERT INTO emp_audit VALUES ('D', current_user, OLD.*); RETURN OLD; ELSIF (TG_OP = 'UPDATE') THEN UPDATE emp SET salary = NEW.salary WHERE empname = OLD.empname; IF NOT FOUND THEN RETURN NULL; END IF; NEW.last_updated = now(); - INSERT INTO emp_audit VALUES('U', current_user, NEW.*); + INSERT INTO emp_audit VALUES ('U', current_user, NEW.*); RETURN NEW; ELSIF (TG_OP = 'INSERT') THEN - INSERT INTO emp VALUES(NEW.empname, NEW.salary); + INSERT INTO emp VALUES (NEW.empname, NEW.salary); NEW.last_updated = now(); - INSERT INTO emp_audit VALUES('I', current_user, NEW.*); + INSERT INTO emp_audit VALUES ('I', current_user, NEW.*); RETURN NEW; END IF; END; @@ -4634,10 +4634,10 @@ CREATE TRIGGER maint_sales_summary_bytime AFTER INSERT OR UPDATE OR DELETE ON sales_fact FOR EACH ROW EXECUTE FUNCTION maint_sales_summary_bytime(); -INSERT INTO sales_fact VALUES(1,1,1,10,3,15); -INSERT INTO sales_fact VALUES(1,2,1,20,5,35); -INSERT INTO sales_fact VALUES(2,2,1,40,15,135); -INSERT INTO sales_fact VALUES(2,3,1,10,1,13); +INSERT INTO sales_fact VALUES (1, 1, 1, 10, 3, 15); +INSERT INTO sales_fact VALUES (1, 2, 1, 20, 5, 35); +INSERT INTO sales_fact VALUES (2, 2, 1, 40, 15, 135); +INSERT INTO sales_fact VALUES (2, 3, 1, 10, 1, 13); SELECT * FROM sales_summary_bytime; DELETE FROM sales_fact WHERE product_key = 1; SELECT * FROM sales_summary_bytime; @@ -4678,7 +4678,7 @@ CREATE TABLE emp ( salary integer ); -CREATE TABLE emp_audit( +CREATE TABLE emp_audit ( operation char(1) NOT NULL, stamp timestamp NOT NULL, userid text NOT NULL, @@ -5226,12 +5226,12 @@ CREATE FUNCTION foo() RETURNS integer AS ' For string literals inside the function body, for example: a_output := ''Blah''; -SELECT * FROM users WHERE f_name=''foobar''; +SELECT * FROM users WHERE f_name = ''foobar''; In the dollar-quoting approach, you'd just write: a_output := 'Blah'; -SELECT * FROM users WHERE f_name='foobar'; +SELECT * FROM users WHERE f_name = 'foobar'; which is exactly what the PL/pgSQL parser would see in either case. @@ -5294,24 +5294,24 @@ a_output := a_output || $$ AND name LIKE 'foobar'$$ . For example: -a_output := a_output || '' if v_'' || - referrer_keys.kind || '' like '''''''''' +a_output := a_output || '' IF v_'' || + referrer_keys.kind || '' LIKE '''''''''' || referrer_keys.key_string || '''''''''' - then return '''''' || referrer_keys.referrer_type - || ''''''; end if;''; + THEN RETURN '''''' || referrer_keys.referrer_type + || ''''''; END IF;''; The value of a_output would then be: -if v_... like ''...'' then return ''...''; end if; +IF v_... LIKE ''...'' THEN RETURN ''...''; END IF; In the dollar-quoting approach, this becomes: -a_output := a_output || $$ if v_$$ || referrer_keys.kind || $$ like '$$ +a_output := a_output || $$ IF v_$$ || referrer_keys.kind || $$ LIKE '$$ || referrer_keys.key_string || $$' - then return '$$ || referrer_keys.referrer_type - || $$'; end if;$$; + THEN RETURN '$$ || referrer_keys.referrer_type + || $$'; END IF;$$; where we assume we only need to put single quote marks into a_output, because it will be re-quoted before use. @@ -5887,7 +5887,7 @@ BEGIN END IF; DELETE FROM cs_active_job; - INSERT INTO cs_active_job(job_id) VALUES (v_job_id); + INSERT INTO cs_active_job (job_id) VALUES (v_job_id); BEGIN INSERT INTO cs_jobs (job_id, start_stamp) VALUES (v_job_id, now()); @@ -5919,7 +5919,7 @@ BEGIN END IF; DELETE FROM cs_active_job; - INSERT INTO cs_active_job(job_id) VALUES (v_job_id); + INSERT INTO cs_active_job (job_id) VALUES (v_job_id); BEGIN INSERT INTO cs_jobs (job_id, start_stamp) VALUES (v_job_id, now()); diff --git a/doc/src/sgml/plpython.sgml b/doc/src/sgml/plpython.sgml index 27c4467ba7d..1c563058142 100644 --- a/doc/src/sgml/plpython.sgml +++ b/doc/src/sgml/plpython.sgml @@ -84,7 +84,7 @@ $$ LANGUAGE plpython3u; defined as: -CREATE FUNCTION pymax (a integer, b integer) +CREATE FUNCTION pymax(a integer, b integer) RETURNS integer AS $$ if a > b: @@ -284,7 +284,7 @@ $$ LANGUAGE plpython3u; we could check for null inputs in the function body: -CREATE FUNCTION pymax (a integer, b integer) +CREATE FUNCTION pymax(a integer, b integer) RETURNS integer AS $$ if (a is None) or (b is None): @@ -384,7 +384,7 @@ CREATE TABLE employee ( age integer ); -CREATE FUNCTION overpaid (e employee) +CREATE FUNCTION overpaid(e employee) RETURNS boolean AS $$ if e["salary"] > 200000: @@ -421,7 +421,7 @@ CREATE TYPE named_value AS ( example: -CREATE FUNCTION make_pair (name text, value integer) +CREATE FUNCTION make_pair(name text, value integer) RETURNS named_value AS $$ return ( name, value ) @@ -448,7 +448,7 @@ $$ LANGUAGE plpython3u; with the column name as key. Example: -CREATE FUNCTION make_pair (name text, value integer) +CREATE FUNCTION make_pair(name text, value integer) RETURNS named_value AS $$ return { "name": name, "value": value } @@ -471,7 +471,7 @@ $$ LANGUAGE plpython3u; Example: -CREATE FUNCTION make_pair (name text, value integer) +CREATE FUNCTION make_pair(name text, value integer) RETURNS named_value AS $$ class named_value: @@ -539,7 +539,7 @@ CREATE TYPE greeting AS ( -CREATE FUNCTION greet (how text) +CREATE FUNCTION greet(how text) RETURNS SETOF greeting AS $$ # return tuple containing lists as composite types @@ -557,7 +557,7 @@ $$ LANGUAGE plpython3u; -CREATE FUNCTION greet (how text) +CREATE FUNCTION greet(how text) RETURNS SETOF greeting AS $$ class producer: @@ -587,7 +587,7 @@ $$ LANGUAGE plpython3u; -CREATE FUNCTION greet (how text) +CREATE FUNCTION greet(how text) RETURNS SETOF greeting AS $$ for who in [ "World", "PostgreSQL", "PL/Python" ]: @@ -1130,7 +1130,7 @@ $$ LANGUAGE plpython3u; CREATE FUNCTION try_adding_joe() RETURNS text AS $$ try: - plpy.execute("INSERT INTO users(username) VALUES ('joe')") + plpy.execute("INSERT INTO users (username) VALUES ('joe')") except plpy.SPIError: return "something went wrong" else: diff --git a/doc/src/sgml/pltcl.sgml b/doc/src/sgml/pltcl.sgml index 5a8e4c9d37e..9fd008a99d7 100644 --- a/doc/src/sgml/pltcl.sgml +++ b/doc/src/sgml/pltcl.sgml @@ -180,7 +180,7 @@ $$ LANGUAGE pltcl; column names. Here is an example: -CREATE FUNCTION square_cube(in int, out squared int, out cubed int) AS $$ +CREATE FUNCTION square_cube(IN int, OUT squared int, OUT cubed int) AS $$ return [list squared [expr {$1 * $1}] cubed [expr {$1 * $1 * $1}]] $$ LANGUAGE pltcl; diff --git a/doc/src/sgml/protocol.sgml b/doc/src/sgml/protocol.sgml index 9d755232873..7546d151830 100644 --- a/doc/src/sgml/protocol.sgml +++ b/doc/src/sgml/protocol.sgml @@ -783,9 +783,9 @@ transaction, unless explicit transaction control commands are included to force a different behavior. For example, if the message contains -INSERT INTO mytable VALUES(1); +INSERT INTO mytable VALUES (1); SELECT 1/0; -INSERT INTO mytable VALUES(2); +INSERT INTO mytable VALUES (2); then the divide-by-zero failure in the SELECT will force rollback of the first INSERT. Furthermore, because @@ -797,9 +797,9 @@ INSERT INTO mytable VALUES(2); If instead the message contains BEGIN; -INSERT INTO mytable VALUES(1); +INSERT INTO mytable VALUES (1); COMMIT; -INSERT INTO mytable VALUES(2); +INSERT INTO mytable VALUES (2); SELECT 1/0; then the first INSERT is committed by the @@ -881,9 +881,9 @@ ROLLBACK; example into BEGIN; -INSERT INTO mytable VALUES(1); +INSERT INTO mytable VALUES (1); COMMIT; -INSERT INTO mytable VALUES(2); +INSERT INTO mytable VALUES (2); SELCT 1/0; then none of the statements would get run, resulting in the visible diff --git a/doc/src/sgml/queries.sgml b/doc/src/sgml/queries.sgml index 2736868fb06..499e22b9ac8 100644 --- a/doc/src/sgml/queries.sgml +++ b/doc/src/sgml/queries.sgml @@ -701,7 +701,7 @@ FROM (VALUES ('anne', 'smith'), ('bob', 'jones'), ('joe', 'blow')) function_call WITH ORDINALITY AS table_alias (column_alias , ... ) -ROWS FROM( function_call , ... ) WITH ORDINALITY AS table_alias (column_alias , ... ) +ROWS FROM ( function_call , ... ) WITH ORDINALITY AS table_alias (column_alias , ... ) @@ -729,7 +729,7 @@ UNNEST( array_expression , ... If no table_alias is specified, the function - name is used as the table name; in the case of a ROWS FROM() + name is used as the table name; in the case of a ROWS FROM construct, the first function's name is used. @@ -778,20 +778,20 @@ SELECT * FROM vw_getfoo; function_call AS alias (column_definition , ... ) function_call AS alias (column_definition , ... ) -ROWS FROM( ... function_call AS (column_definition , ... ) , ... ) +ROWS FROM ( ... function_call AS (column_definition , ... ) , ... ) - When not using the ROWS FROM() syntax, + When not using the ROWS FROM syntax, the column_definition list replaces the column alias list that could otherwise be attached to the FROM item; the names in the column definitions serve as column aliases. - When using the ROWS FROM() syntax, + When using the ROWS FROM syntax, a column_definition list can be attached to each member function separately; or if there is only one member function and no WITH ORDINALITY clause, a column_definition list can be written in - place of a column alias list following ROWS FROM(). + place of a column alias list following ROWS FROM. @@ -2232,7 +2232,7 @@ WITH RECURSIVE included_parts(sub_part, part, quantity) AS ( FROM included_parts pr, parts p WHERE p.part = pr.sub_part ) -SELECT sub_part, SUM(quantity) as total_quantity +SELECT sub_part, SUM(quantity) AS total_quantity FROM included_parts GROUP BY sub_part @@ -2603,7 +2603,7 @@ WHERE w2.key = 123; undesirable is WITH w AS ( - SELECT key, very_expensive_function(val) as f FROM some_table + SELECT key, very_expensive_function(val) AS f FROM some_table ) SELECT * FROM w AS w1 JOIN w AS w2 ON w1.f = w2.f; diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml index bea9f90138b..9d23ad5a0fb 100644 --- a/doc/src/sgml/ref/alter_table.sgml +++ b/doc/src/sgml/ref/alter_table.sgml @@ -1642,7 +1642,7 @@ ALTER TABLE measurements ALTER TABLE transactions ADD COLUMN status varchar(30) DEFAULT 'old', - ALTER COLUMN status SET default 'current'; + ALTER COLUMN status SET DEFAULT 'current'; Existing rows will be filled with old, but then the default for subsequent commands will be current. diff --git a/doc/src/sgml/ref/alter_view.sgml b/doc/src/sgml/ref/alter_view.sgml index afbb3d02c7b..7c67c708308 100644 --- a/doc/src/sgml/ref/alter_view.sgml +++ b/doc/src/sgml/ref/alter_view.sgml @@ -205,8 +205,8 @@ ALTER VIEW foo RENAME TO bar; CREATE TABLE base_table (id int, ts timestamptz); CREATE VIEW a_view AS SELECT * FROM base_table; ALTER VIEW a_view ALTER COLUMN ts SET DEFAULT now(); -INSERT INTO base_table(id) VALUES(1); -- ts will receive a NULL -INSERT INTO a_view(id) VALUES(2); -- ts will receive the current time +INSERT INTO base_table (id) VALUES (1); -- ts will receive a NULL +INSERT INTO a_view (id) VALUES (2); -- ts will receive the current time diff --git a/doc/src/sgml/ref/create_domain.sgml b/doc/src/sgml/ref/create_domain.sgml index c111285a69c..c2329014ded 100644 --- a/doc/src/sgml/ref/create_domain.sgml +++ b/doc/src/sgml/ref/create_domain.sgml @@ -256,7 +256,7 @@ INSERT INTO tab (domcol) VALUES ((SELECT domcol FROM tab WHERE false)); CREATE DOMAIN us_postal_code AS TEXT -CHECK( +CHECK ( VALUE ~ '^\d{5}$' OR VALUE ~ '^\d{5}-\d{4}$' ); diff --git a/doc/src/sgml/ref/create_function.sgml b/doc/src/sgml/ref/create_function.sgml index 0d240484cd3..87e331f13bd 100644 --- a/doc/src/sgml/ref/create_function.sgml +++ b/doc/src/sgml/ref/create_function.sgml @@ -649,7 +649,7 @@ END parameters. Thus for example these declarations conflict: CREATE FUNCTION foo(int) ... -CREATE FUNCTION foo(int, out text) ... +CREATE FUNCTION foo(int, OUT text) ... @@ -676,9 +676,9 @@ CREATE FUNCTION foo(int, int default 42) ... parenthesized type modifiers (e.g., the precision field for type numeric) are discarded by CREATE FUNCTION. Thus for example - CREATE FUNCTION foo (varchar(10)) ... + CREATE FUNCTION foo(varchar(10)) ... is exactly the same as - CREATE FUNCTION foo (varchar) .... + CREATE FUNCTION foo(varchar) .... @@ -709,7 +709,7 @@ CREATE FUNCTION foo(int, int default 42) ... Add two integers using an SQL function: CREATE FUNCTION add(integer, integer) RETURNS integer - AS 'select $1 + $2;' + AS 'SELECT $1 + $2;' LANGUAGE SQL IMMUTABLE RETURNS NULL ON NULL INPUT; @@ -740,7 +740,7 @@ $$ LANGUAGE plpgsql; Return a record containing multiple output parameters: -CREATE FUNCTION dup(in int, out f1 int, out f2 text) +CREATE FUNCTION dup(IN int, OUT f1 int, OUT f2 text) AS $$ SELECT $1, CAST($1 AS text) || ' is text' $$ LANGUAGE SQL; @@ -760,7 +760,7 @@ SELECT * FROM dup(42); Another way to return multiple columns is to use a TABLE function: -CREATE FUNCTION dup(int) RETURNS TABLE(f1 int, f2 text) +CREATE FUNCTION dup(int) RETURNS TABLE (f1 int, f2 text) AS $$ SELECT $1, CAST($1 AS text) || ' is text' $$ LANGUAGE SQL; diff --git a/doc/src/sgml/ref/create_table.sgml b/doc/src/sgml/ref/create_table.sgml index a157a244e4e..0bd31315ac7 100644 --- a/doc/src/sgml/ref/create_table.sgml +++ b/doc/src/sgml/ref/create_table.sgml @@ -2088,7 +2088,7 @@ CREATE TABLE films ( date_prod date, kind varchar(10), len interval hour to minute, - CONSTRAINT production UNIQUE(date_prod) + CONSTRAINT production UNIQUE (date_prod) ); @@ -2128,7 +2128,7 @@ CREATE TABLE films ( date_prod date, kind varchar(10), len interval hour to minute, - CONSTRAINT code_title PRIMARY KEY(code,title) + CONSTRAINT code_title PRIMARY KEY (code, title) ); @@ -2143,7 +2143,7 @@ CREATE TABLE films ( CREATE TABLE distributors ( did integer, name varchar(40), - PRIMARY KEY(did) + PRIMARY KEY (did) ); CREATE TABLE distributors ( @@ -2199,7 +2199,7 @@ CREATE TABLE distributors ( CREATE TABLE distributors ( did integer, name varchar(40), - UNIQUE(name) + UNIQUE (name) ); @@ -2212,7 +2212,7 @@ CREATE TABLE distributors ( CREATE TABLE distributors ( did integer, name varchar(40), - UNIQUE(name) WITH (fillfactor=70) + UNIQUE (name) WITH (fillfactor=70) ) WITH (fillfactor=70); @@ -2257,7 +2257,7 @@ CREATE TABLE employees OF employee_type ( Create a range partitioned table: CREATE TABLE measurement ( - logdate date not null, + logdate date NOT NULL, peaktemp int, unitsales int ) PARTITION BY RANGE (logdate); @@ -2267,7 +2267,7 @@ CREATE TABLE measurement ( Create a range partitioned table with multiple columns in the partition key: CREATE TABLE measurement_year_month ( - logdate date not null, + logdate date NOT NULL, peaktemp int, unitsales int ) PARTITION BY RANGE (EXTRACT(YEAR FROM logdate), EXTRACT(MONTH FROM logdate)); @@ -2277,8 +2277,8 @@ CREATE TABLE measurement_year_month ( Create a list partitioned table: CREATE TABLE cities ( - city_id bigserial not null, - name text not null, + city_id bigserial NOT NULL, + name text NOT NULL, population bigint ) PARTITION BY LIST (left(lower(name), 1)); @@ -2287,8 +2287,8 @@ CREATE TABLE cities ( Create a hash partitioned table: CREATE TABLE orders ( - order_id bigint not null, - cust_id bigint not null, + order_id bigint NOT NULL, + cust_id bigint NOT NULL, status text ) PARTITION BY HASH (order_id); @@ -2528,7 +2528,7 @@ CREATE TABLE cities_partdef PostgreSQL allows a table of no columns - to be created (for example, CREATE TABLE foo();). This + to be created (for example, CREATE TABLE foo ();). This is an extension from the SQL standard, which does not allow zero-column tables. Zero-column tables are not in themselves very useful, but disallowing them creates odd special cases for ALTER TABLE diff --git a/doc/src/sgml/ref/merge.sgml b/doc/src/sgml/ref/merge.sgml index c2e181066a4..c02f1946286 100644 --- a/doc/src/sgml/ref/merge.sgml +++ b/doc/src/sgml/ref/merge.sgml @@ -749,7 +749,7 @@ MERGE INTO wines w USING wine_stock_changes s ON s.winename = w.winename WHEN NOT MATCHED AND s.stock_delta > 0 THEN - INSERT VALUES(s.winename, s.stock_delta) + INSERT VALUES (s.winename, s.stock_delta) WHEN MATCHED AND w.stock + s.stock_delta > 0 THEN UPDATE SET stock = w.stock + s.stock_delta WHEN MATCHED THEN @@ -770,7 +770,7 @@ MERGE INTO wines w USING new_wine_list s ON s.winename = w.winename WHEN NOT MATCHED BY TARGET THEN - INSERT VALUES(s.winename, s.stock) + INSERT VALUES (s.winename, s.stock) WHEN MATCHED AND w.stock != s.stock THEN UPDATE SET stock = s.stock WHEN NOT MATCHED BY SOURCE THEN diff --git a/doc/src/sgml/ref/pg_rewind.sgml b/doc/src/sgml/ref/pg_rewind.sgml index 928e78cda33..5b155cfa12a 100644 --- a/doc/src/sgml/ref/pg_rewind.sgml +++ b/doc/src/sgml/ref/pg_rewind.sgml @@ -372,10 +372,10 @@ PostgreSQL documentation a role, named rewind_user here: CREATE USER rewind_user LOGIN; -GRANT EXECUTE ON function pg_catalog.pg_ls_dir(text, boolean, boolean) TO rewind_user; -GRANT EXECUTE ON function pg_catalog.pg_stat_file(text, boolean) TO rewind_user; -GRANT EXECUTE ON function pg_catalog.pg_read_binary_file(text) TO rewind_user; -GRANT EXECUTE ON function pg_catalog.pg_read_binary_file(text, bigint, bigint, boolean) TO rewind_user; +GRANT EXECUTE ON FUNCTION pg_catalog.pg_ls_dir(text, boolean, boolean) TO rewind_user; +GRANT EXECUTE ON FUNCTION pg_catalog.pg_stat_file(text, boolean) TO rewind_user; +GRANT EXECUTE ON FUNCTION pg_catalog.pg_read_binary_file(text) TO rewind_user; +GRANT EXECUTE ON FUNCTION pg_catalog.pg_read_binary_file(text, bigint, bigint, boolean) TO rewind_user; diff --git a/doc/src/sgml/ref/prepare.sgml b/doc/src/sgml/ref/prepare.sgml index 8ee9439f611..998c5e4519c 100644 --- a/doc/src/sgml/ref/prepare.sgml +++ b/doc/src/sgml/ref/prepare.sgml @@ -217,7 +217,7 @@ EXPLAIN EXECUTE name(parameter_values PREPARE fooplan (int, text, bool, numeric) AS - INSERT INTO foo VALUES($1, $2, $3, $4); + INSERT INTO foo VALUES ($1, $2, $3, $4); EXECUTE fooplan(1, 'Hunter Valley', 't', 200.00); diff --git a/doc/src/sgml/ref/psql-ref.sgml b/doc/src/sgml/ref/psql-ref.sgml index 7e96a8e1ddb..1ab427d18af 100644 --- a/doc/src/sgml/ref/psql-ref.sgml +++ b/doc/src/sgml/ref/psql-ref.sgml @@ -2531,7 +2531,7 @@ Tue Oct 26 21:40:57 CEST 1999 statement to be executed. For example, to create an index on each column of my_table: -=> SELECT format('create index on my_table(%I)', attname) +=> SELECT format('CREATE INDEX ON my_table (%I)', attname) -> FROM pg_attribute -> WHERE attrelid = 'my_table'::regclass AND attnum > 0 -> ORDER BY attnum @@ -2766,8 +2766,8 @@ hello 10 -- check for the existence of two separate records in the database and store -- the results in separate psql variables SELECT - EXISTS(SELECT 1 FROM customer WHERE customer_id = 123) as is_customer, - EXISTS(SELECT 1 FROM employee WHERE employee_id = 456) as is_employee + EXISTS (SELECT 1 FROM customer WHERE customer_id = 123) AS is_customer, + EXISTS (SELECT 1 FROM employee WHERE employee_id = 456) AS is_employee \gset \if :is_customer SELECT * FROM customer WHERE customer_id = 123; @@ -4023,7 +4023,7 @@ SELECT 1 \bind \sendpipeline server as soon as it reaches the command-ending semicolon, even if more input remains on the current line. Thus for example entering -select 1; select 2; select 3; +SELECT 1; SELECT 2; SELECT 3; will result in the three SQL commands being individually sent to the server, with each one's results being displayed before @@ -4032,7 +4032,7 @@ select 1; select 2; select 3; command before it and the one after are effectively combined and sent to the server in one request. So for example -select 1\; select 2\; select 3; +SELECT 1\; SELECT 2\; SELECT 3; results in sending the three SQL commands to the server in a single request, when the non-backslashed semicolon is reached. @@ -5581,7 +5581,7 @@ PSQL_EDITOR_LINENUMBER_ARG='--line ' input. Notice the changing prompt: testdb=> CREATE TABLE my_table ( -testdb(> first integer not null default 0, +testdb(> first integer NOT NULL DEFAULT 0, testdb(> second text) testdb-> ; CREATE TABLE @@ -5770,8 +5770,8 @@ testdb=> \crosstabview first second This second example shows a multiplication table with rows sorted in reverse numerical order and columns with an independent, ascending numerical order. -testdb=> SELECT t1.first as "A", t2.first+100 AS "B", t1.first*(t2.first+100) as "AxB", -testdb-> row_number() over(order by t2.first) AS ord +testdb=> SELECT t1.first AS "A", t2.first+100 AS "B", t1.first*(t2.first+100) AS "AxB", +testdb-> row_number() OVER (ORDER BY t2.first) AS ord testdb-> FROM my_table t1 CROSS JOIN my_table t2 ORDER BY 1 DESC testdb-> \crosstabview "A" "B" "AxB" ord A | 101 | 102 | 103 | 104 diff --git a/doc/src/sgml/ref/select.sgml b/doc/src/sgml/ref/select.sgml index 5a3bcff7607..9c78252dd0b 100644 --- a/doc/src/sgml/ref/select.sgml +++ b/doc/src/sgml/ref/select.sgml @@ -57,7 +57,7 @@ SELECT [ ALL | DISTINCT [ ON ( expressionalias [ ( column_alias [, ...] ) ] ] [ LATERAL ] function_name ( [ argument [, ...] ] ) [ AS ] alias ( column_definition [, ...] ) [ LATERAL ] function_name ( [ argument [, ...] ] ) AS ( column_definition [, ...] ) - [ LATERAL ] ROWS FROM( function_name ( [ argument [, ...] ] ) [ AS ( column_definition [, ...] ) ] [, ...] ) + [ LATERAL ] ROWS FROM ( function_name ( [ argument [, ...] ] ) [ AS ( column_definition [, ...] ) ] [, ...] ) [ WITH ORDINALITY ] [ [ AS ] alias [ ( column_alias [, ...] ) ] ] from_item join_type from_item { ON join_condition | USING ( join_column [, ...] ) [ AS join_using_alias ] } from_item NATURAL join_type from_item @@ -551,7 +551,7 @@ TABLE [ ONLY ] table_name [ * ] Multiple function calls can be combined into a single FROM-clause item by surrounding them - with ROWS FROM( ... ). The output of such an item is the + with ROWS FROM ( ... ). The output of such an item is the concatenation of the first row from each function, then the second row from each function, etc. If some of the functions produce fewer rows than others, null values are substituted for the missing data, so @@ -571,18 +571,18 @@ TABLE [ ONLY ] table_name [ * ] - When using the ROWS FROM( ... ) syntax, if one of the + When using the ROWS FROM ( ... ) syntax, if one of the functions requires a column definition list, it's preferred to put the column definition list after the function call inside - ROWS FROM( ... ). A column definition list can be placed - after the ROWS FROM( ... ) construct only if there's just + ROWS FROM ( ... ). A column definition list can be placed + after the ROWS FROM ( ... ) construct only if there's just a single function and no WITH ORDINALITY clause. To use ORDINALITY together with a column definition - list, you must use the ROWS FROM( ... ) syntax and put the - column definition list inside ROWS FROM( ... ). + list, you must use the ROWS FROM ( ... ) syntax and put the + column definition list inside ROWS FROM ( ... ). @@ -1927,7 +1927,7 @@ SELECT * FROM unnest(ARRAY['a','b','c','d','e','f']) WITH ORDINALITY; WITH t AS ( - SELECT random() as x FROM generate_series(1, 3) + SELECT random() AS x FROM generate_series(1, 3) ) SELECT * FROM t UNION ALL @@ -2209,7 +2209,7 @@ SELECT 2+2; - ROWS FROM( ... ) is an extension of the SQL standard. + ROWS FROM ( ... ) is an extension of the SQL standard. diff --git a/doc/src/sgml/ref/update.sgml b/doc/src/sgml/ref/update.sgml index 40cca063946..f96858def56 100644 --- a/doc/src/sgml/ref/update.sgml +++ b/doc/src/sgml/ref/update.sgml @@ -458,7 +458,7 @@ UPDATE summary s SET (sum_x, sum_y, avg_x, avg_y) = BEGIN; -- other operations SAVEPOINT sp1; -INSERT INTO wines VALUES('Chateau Lafite 2003', '24'); +INSERT INTO wines VALUES ('Chateau Lafite 2003', '24'); -- Assume the above fails because of a unique key violation, -- so now we issue these commands: ROLLBACK TO sp1; diff --git a/doc/src/sgml/ref/values.sgml b/doc/src/sgml/ref/values.sgml index 4bf7bfdffee..49131dd884b 100644 --- a/doc/src/sgml/ref/values.sgml +++ b/doc/src/sgml/ref/values.sgml @@ -190,11 +190,11 @@ INSERT INTO films VALUES SELECT f.* - FROM films f, (VALUES('MGM', 'Horror'), ('UA', 'Sci-Fi')) AS t (studio, kind) + FROM films f, (VALUES ('MGM', 'Horror'), ('UA', 'Sci-Fi')) AS t (studio, kind) WHERE f.studio = t.studio AND f.kind = t.kind; UPDATE employees SET salary = salary * v.increase - FROM (VALUES(1, 200000, 1.2), (2, 400000, 1.4)) AS v (depno, target, increase) + FROM (VALUES (1, 200000, 1.2), (2, 400000, 1.4)) AS v (depno, target, increase) WHERE employees.depno = v.depno AND employees.sales >= v.target; @@ -216,7 +216,7 @@ UPDATE employees SET salary = salary * v.increase SELECT * FROM machines -WHERE ip_address IN (VALUES('192.168.0.1'::inet), ('192.168.0.10'), ('192.168.1.43')); +WHERE ip_address IN (VALUES ('192.168.0.1'::inet), ('192.168.0.10'), ('192.168.1.43')); diff --git a/doc/src/sgml/rowtypes.sgml b/doc/src/sgml/rowtypes.sgml index bbeac84d46a..31958076eb6 100644 --- a/doc/src/sgml/rowtypes.sgml +++ b/doc/src/sgml/rowtypes.sgml @@ -218,9 +218,9 @@ SELECT (my_func(...)).field FROM ... First, inserting or updating a whole column: -INSERT INTO mytab (complex_col) VALUES((1.1,2.2)); +INSERT INTO mytab (complex_col) VALUES ((1.1, 2.2)); -UPDATE mytab SET complex_col = ROW(1.1,2.2) WHERE ...; +UPDATE mytab SET complex_col = ROW(1.1, 2.2) WHERE ...; The first example omits ROW, the second uses it; we @@ -244,7 +244,7 @@ UPDATE mytab SET complex_col.r = (complex_col).r + 1 WHERE ...; And we can specify subfields as targets for INSERT, too: -INSERT INTO mytab (complex_col.r, complex_col.i) VALUES(1.1, 2.2); +INSERT INTO mytab (complex_col.r, complex_col.i) VALUES (1.1, 2.2); Had we not supplied values for all the subfields of the column, the diff --git a/doc/src/sgml/rules.sgml b/doc/src/sgml/rules.sgml index 282dcd722d4..50ac9bd4bdb 100644 --- a/doc/src/sgml/rules.sgml +++ b/doc/src/sgml/rules.sgml @@ -968,7 +968,7 @@ CREATE MATERIALIZED VIEW sales_summary AS SELECT seller_no, invoice_date, - sum(invoice_amt)::numeric(13,2) as sales_amt + sum(invoice_amt)::numeric(13,2) AS sales_amt FROM invoice WHERE invoice_date < CURRENT_DATE GROUP BY diff --git a/doc/src/sgml/seg.sgml b/doc/src/sgml/seg.sgml index dc66e24f2f5..d2d37176835 100644 --- a/doc/src/sgml/seg.sgml +++ b/doc/src/sgml/seg.sgml @@ -46,7 +46,7 @@ when you fetch it? Watch: -test=> select 6.50 :: float8 as "pH"; +test=> SELECT 6.50::float8 AS "pH"; pH --- 6.5 @@ -72,7 +72,7 @@ test=> select 6.50 :: float8 as "pH"; Check this out: -test=> select '6.25 .. 6.50'::seg as "pH"; +test=> SELECT '6.25 .. 6.50'::seg AS "pH"; pH ------------ 6.25 .. 6.50 diff --git a/doc/src/sgml/syntax.sgml b/doc/src/sgml/syntax.sgml index 237d7306fe8..82b4489fb47 100644 --- a/doc/src/sgml/syntax.sgml +++ b/doc/src/sgml/syntax.sgml @@ -2331,7 +2331,7 @@ SELECT ARRAY[[1,2],[3,4]]; an array of the proper kind, not only a sub-ARRAY construct. For example: -CREATE TABLE arr(f1 int[], f2 int[]); +CREATE TABLE arr (f1 int[], f2 int[]); INSERT INTO arr VALUES (ARRAY[[1,2],[3,4]], ARRAY[[5,6],[7,8]]); @@ -2418,7 +2418,7 @@ SELECT ARRAY(SELECT ARRAY[i, i*2] FROM generate_series(1,5) AS a(i)); expressions (separated by commas) for the row field values, and finally a right parenthesis. For example: -SELECT ROW(1,2.5,'this is a test'); +SELECT ROW(1, 2.5, 'this is a test'); The key word ROW is optional when there is more than one expression in the list. @@ -2457,12 +2457,12 @@ SELECT ROW(t.f1, t.f2, 42) FROM t; created with CREATE TYPE AS. An explicit cast might be needed to avoid ambiguity. For example: -CREATE TABLE mytable(f1 int, f2 float, f3 text); +CREATE TABLE mytable (f1 int, f2 float, f3 text); CREATE FUNCTION getf1(mytable) RETURNS int AS 'SELECT $1.f1' LANGUAGE SQL; -- No cast needed since only one getf1() exists -SELECT getf1(ROW(1,2.5,'this is a test')); +SELECT getf1(ROW(1, 2.5, 'this is a test')); getf1 ------- 1 @@ -2473,16 +2473,16 @@ CREATE TYPE myrowtype AS (f1 int, f2 text, f3 numeric); CREATE FUNCTION getf1(myrowtype) RETURNS int AS 'SELECT $1.f1' LANGUAGE SQL; -- Now we need a cast to indicate which function to call: -SELECT getf1(ROW(1,2.5,'this is a test')); +SELECT getf1(ROW(1, 2.5, 'this is a test')); ERROR: function getf1(record) is not unique -SELECT getf1(ROW(1,2.5,'this is a test')::mytable); +SELECT getf1(ROW(1, 2.5, 'this is a test')::mytable); getf1 ------- 1 (1 row) -SELECT getf1(CAST(ROW(11,'this is a test',2.5) AS myrowtype)); +SELECT getf1(CAST(ROW(11, 'this is a test', 2.5) AS myrowtype)); getf1 ------- 11 diff --git a/doc/src/sgml/tablefunc.sgml b/doc/src/sgml/tablefunc.sgml index e10fe7009d1..68fc806ce4d 100644 --- a/doc/src/sgml/tablefunc.sgml +++ b/doc/src/sgml/tablefunc.sgml @@ -281,22 +281,22 @@ SELECT * FROM crosstab('...') AS ct(row_name text, category_1 text, category_2 t Here is a complete example: -CREATE TABLE ct(id SERIAL, rowid TEXT, attribute TEXT, value TEXT); -INSERT INTO ct(rowid, attribute, value) VALUES('test1','att1','val1'); -INSERT INTO ct(rowid, attribute, value) VALUES('test1','att2','val2'); -INSERT INTO ct(rowid, attribute, value) VALUES('test1','att3','val3'); -INSERT INTO ct(rowid, attribute, value) VALUES('test1','att4','val4'); -INSERT INTO ct(rowid, attribute, value) VALUES('test2','att1','val5'); -INSERT INTO ct(rowid, attribute, value) VALUES('test2','att2','val6'); -INSERT INTO ct(rowid, attribute, value) VALUES('test2','att3','val7'); -INSERT INTO ct(rowid, attribute, value) VALUES('test2','att4','val8'); +CREATE TABLE ct (id SERIAL, rowid TEXT, attribute TEXT, value TEXT); +INSERT INTO ct (rowid, attribute, value) VALUES ('test1', 'att1', 'val1'); +INSERT INTO ct (rowid, attribute, value) VALUES ('test1', 'att2', 'val2'); +INSERT INTO ct (rowid, attribute, value) VALUES ('test1', 'att3', 'val3'); +INSERT INTO ct (rowid, attribute, value) VALUES ('test1', 'att4', 'val4'); +INSERT INTO ct (rowid, attribute, value) VALUES ('test2', 'att1', 'val5'); +INSERT INTO ct (rowid, attribute, value) VALUES ('test2', 'att2', 'val6'); +INSERT INTO ct (rowid, attribute, value) VALUES ('test2', 'att3', 'val7'); +INSERT INTO ct (rowid, attribute, value) VALUES ('test2', 'att4', 'val8'); SELECT * FROM crosstab( - 'select rowid, attribute, value - from ct - where attribute = ''att2'' or attribute = ''att3'' - order by 1,2') + 'SELECT rowid, attribute, value + FROM ct + WHERE attribute = ''att2'' OR attribute = ''att3'' + ORDER BY 1,2') AS ct(row_name text, category_1 text, category_2 text, category_3 text); row_name | category_1 | category_2 | category_3 @@ -371,10 +371,10 @@ CREATE TYPE tablefunc_crosstab_N AS ( SELECT * FROM crosstab3( - 'select rowid, attribute, value - from ct - where attribute = ''att2'' or attribute = ''att3'' - order by 1,2'); + 'SELECT rowid, attribute, value + FROM ct + WHERE attribute = ''att2'' OR attribute = ''att3'' + ORDER BY 1,2'); @@ -407,7 +407,7 @@ CREATE TYPE my_crosstab_float8_5_cols AS ( ); CREATE OR REPLACE FUNCTION crosstab_float8_5_cols(text) - RETURNS setof my_crosstab_float8_5_cols + RETURNS SETOF my_crosstab_float8_5_cols AS '$libdir/tablefunc','crosstab' LANGUAGE C STABLE STRICT; @@ -426,7 +426,7 @@ CREATE OR REPLACE FUNCTION crosstab_float8_5_cols( OUT my_category_3 float8, OUT my_category_4 float8, OUT my_category_5 float8) - RETURNS setof record + RETURNS SETOF record AS '$libdir/tablefunc','crosstab' LANGUAGE C STABLE STRICT; @@ -572,18 +572,18 @@ row_name extra cat1 cat2 cat3 cat4 Here are two complete examples: -create table sales(year int, month int, qty int); -insert into sales values(2007, 1, 1000); -insert into sales values(2007, 2, 1500); -insert into sales values(2007, 7, 500); -insert into sales values(2007, 11, 1500); -insert into sales values(2007, 12, 2000); -insert into sales values(2008, 1, 1000); - -select * from crosstab( - 'select year, month, qty from sales order by 1', - 'select m from generate_series(1,12) m' -) as ( +CREATE TABLE sales (year int, month int, qty int); +INSERT INTO sales VALUES (2007, 1, 1000); +INSERT INTO sales VALUES (2007, 2, 1500); +INSERT INTO sales VALUES (2007, 7, 500); +INSERT INTO sales VALUES (2007, 11, 1500); +INSERT INTO sales VALUES (2007, 12, 2000); +INSERT INTO sales VALUES (2008, 1, 1000); + +SELECT * FROM crosstab( + 'SELECT year, month, qty FROM sales ORDER BY 1', + 'SELECT m FROM generate_series(1, 12) m' +) AS ( year int, "Jan" int, "Feb" int, @@ -606,14 +606,14 @@ select * from crosstab( -CREATE TABLE cth(rowid text, rowdt timestamp, attribute text, val text); -INSERT INTO cth VALUES('test1','01 March 2003','temperature','42'); -INSERT INTO cth VALUES('test1','01 March 2003','test_result','PASS'); -INSERT INTO cth VALUES('test1','01 March 2003','volts','2.6987'); -INSERT INTO cth VALUES('test2','02 March 2003','temperature','53'); -INSERT INTO cth VALUES('test2','02 March 2003','test_result','FAIL'); -INSERT INTO cth VALUES('test2','02 March 2003','test_startdate','01 March 2003'); -INSERT INTO cth VALUES('test2','02 March 2003','volts','3.1234'); +CREATE TABLE cth (rowid text, rowdt timestamp, attribute text, val text); +INSERT INTO cth VALUES ('test1', '01 March 2003', 'temperature', '42'); +INSERT INTO cth VALUES ('test1', '01 March 2003', 'test_result', 'PASS'); +INSERT INTO cth VALUES ('test1', '01 March 2003', 'volts', '2.6987'); +INSERT INTO cth VALUES ('test2', '02 March 2003', 'temperature', '53'); +INSERT INTO cth VALUES ('test2', '02 March 2003', 'test_result', 'FAIL'); +INSERT INTO cth VALUES ('test2', '02 March 2003', 'test_startdate', '01 March 2003'); +INSERT INTO cth VALUES ('test2', '02 March 2003', 'volts', '3.1234'); SELECT * FROM crosstab ( @@ -784,17 +784,17 @@ SELECT * FROM connectby('connectby_tree', 'keyid', 'parent_keyid', 'pos', 'row2' Here is an example: -CREATE TABLE connectby_tree(keyid text, parent_keyid text, pos int); - -INSERT INTO connectby_tree VALUES('row1',NULL, 0); -INSERT INTO connectby_tree VALUES('row2','row1', 0); -INSERT INTO connectby_tree VALUES('row3','row1', 0); -INSERT INTO connectby_tree VALUES('row4','row2', 1); -INSERT INTO connectby_tree VALUES('row5','row2', 0); -INSERT INTO connectby_tree VALUES('row6','row4', 0); -INSERT INTO connectby_tree VALUES('row7','row3', 0); -INSERT INTO connectby_tree VALUES('row8','row6', 0); -INSERT INTO connectby_tree VALUES('row9','row5', 0); +CREATE TABLE connectby_tree (keyid text, parent_keyid text, pos int); + +INSERT INTO connectby_tree VALUES ('row1', NULL, 0); +INSERT INTO connectby_tree VALUES ('row2', 'row1', 0); +INSERT INTO connectby_tree VALUES ('row3', 'row1', 0); +INSERT INTO connectby_tree VALUES ('row4', 'row2', 1); +INSERT INTO connectby_tree VALUES ('row5', 'row2', 0); +INSERT INTO connectby_tree VALUES ('row6', 'row4', 0); +INSERT INTO connectby_tree VALUES ('row7', 'row3', 0); +INSERT INTO connectby_tree VALUES ('row8', 'row6', 0); +INSERT INTO connectby_tree VALUES ('row9', 'row5', 0); -- with branch, without orderby_fld (order of results is not guaranteed) SELECT * FROM connectby('connectby_tree', 'keyid', 'parent_keyid', 'row2', 0, '~') diff --git a/doc/src/sgml/tcn.sgml b/doc/src/sgml/tcn.sgml index 32a1025cc6b..98278fbee37 100644 --- a/doc/src/sgml/tcn.sgml +++ b/doc/src/sgml/tcn.sgml @@ -43,32 +43,32 @@ A brief example of using the extension follows. -test=# create table tcndata +test=# CREATE TABLE tcndata test-# ( -test(# a int not null, -test(# b date not null, +test(# a int NOT NULL, +test(# b date NOT NULL, test(# c text, -test(# primary key (a, b) +test(# PRIMARY KEY (a, b) test(# ); CREATE TABLE -test=# create trigger tcndata_tcn_trigger -test-# after insert or update or delete on tcndata -test-# for each row execute function triggered_change_notification(); +test=# CREATE TRIGGER tcndata_tcn_trigger +test-# AFTER INSERT OR UPDATE OR DELETE ON tcndata +test-# FOR EACH ROW EXECUTE FUNCTION triggered_change_notification(); CREATE TRIGGER -test=# listen tcn; +test=# LISTEN tcn; LISTEN -test=# insert into tcndata values (1, date '2012-12-22', 'one'), +test=# INSERT INTO tcndata VALUES (1, date '2012-12-22', 'one'), test-# (1, date '2012-12-23', 'another'), test-# (2, date '2012-12-23', 'two'); INSERT 0 3 Asynchronous notification "tcn" with payload ""tcndata",I,"a"='1',"b"='2012-12-22'" received from server process with PID 22770. Asynchronous notification "tcn" with payload ""tcndata",I,"a"='1',"b"='2012-12-23'" received from server process with PID 22770. Asynchronous notification "tcn" with payload ""tcndata",I,"a"='2',"b"='2012-12-23'" received from server process with PID 22770. -test=# update tcndata set c = 'uno' where a = 1; +test=# UPDATE tcndata SET c = 'uno' WHERE a = 1; UPDATE 2 Asynchronous notification "tcn" with payload ""tcndata",U,"a"='1',"b"='2012-12-22'" received from server process with PID 22770. Asynchronous notification "tcn" with payload ""tcndata",U,"a"='1',"b"='2012-12-23'" received from server process with PID 22770. -test=# delete from tcndata where a = 1 and b = date '2012-12-22'; +test=# DELETE FROM tcndata WHERE a = 1 AND b = date '2012-12-22'; DELETE 1 Asynchronous notification "tcn" with payload ""tcndata",D,"a"='1',"b"='2012-12-22'" received from server process with PID 22770. diff --git a/doc/src/sgml/textsearch.sgml b/doc/src/sgml/textsearch.sgml index 89928ed1829..2b79761af0f 100644 --- a/doc/src/sgml/textsearch.sgml +++ b/doc/src/sgml/textsearch.sgml @@ -1817,7 +1817,7 @@ SELECT ts_rewrite('a & b'::tsquery, 'a'::tsquery, 'c'::tsquery); CREATE TABLE aliases (t tsquery PRIMARY KEY, s tsquery); -INSERT INTO aliases VALUES('a', 'c'); +INSERT INTO aliases VALUES ('a', 'c'); SELECT ts_rewrite('a & b'::tsquery, 'SELECT t,s FROM aliases'); ts_rewrite @@ -1842,7 +1842,7 @@ SELECT ts_rewrite('a & b'::tsquery, 'SELECT t,s FROM aliases'); CREATE TABLE aliases (t tsquery primary key, s tsquery); -INSERT INTO aliases VALUES(to_tsquery('supernovae'), to_tsquery('supernovae|sn')); +INSERT INTO aliases VALUES (to_tsquery('supernovae'), to_tsquery('supernovae|sn')); SELECT ts_rewrite(to_tsquery('supernovae & crab'), 'SELECT * FROM aliases'); ts_rewrite @@ -1930,7 +1930,7 @@ CREATE TRIGGER tsvectorupdate BEFORE INSERT OR UPDATE ON messages FOR EACH ROW EXECUTE FUNCTION tsvector_update_trigger(tsv, 'pg_catalog.english', title, body); -INSERT INTO messages VALUES('title here', 'the body text is here'); +INSERT INTO messages VALUES ('title here', 'the body text is here'); SELECT * FROM messages; title | body | tsv @@ -1974,12 +1974,12 @@ SELECT title, body FROM messages WHERE tsv @@ to_tsquery('title & body'); CREATE FUNCTION messages_trigger() RETURNS trigger AS $$ -begin +BEGIN new.tsv := setweight(to_tsvector('pg_catalog.english', coalesce(new.title,'')), 'A') || setweight(to_tsvector('pg_catalog.english', coalesce(new.body,'')), 'D'); - return new; -end + RETURN new; +END $$ LANGUAGE plpgsql; CREATE TRIGGER tsvectorupdate BEFORE INSERT OR UPDATE diff --git a/doc/src/sgml/typeconv.sgml b/doc/src/sgml/typeconv.sgml index 1707bd884dc..8e11e91e815 100644 --- a/doc/src/sgml/typeconv.sgml +++ b/doc/src/sgml/typeconv.sgml @@ -490,7 +490,7 @@ SELECT ~ CAST('20' AS int8) AS "negation"; Here is another example of resolving an operator with one known and one unknown input: -SELECT array[1,2] <@ '{1,2,3}' as "is subset"; +SELECT ARRAY[1,2] <@ '{1,2,3}' AS "is subset"; is subset ----------- @@ -523,8 +523,8 @@ This is possible but is not nearly as useful as it might seem, because the operator resolution rules are designed to select operators applying to the domain's base type. As an example consider -CREATE DOMAIN mytext AS text CHECK(...); -CREATE FUNCTION mytext_eq_text (mytext, text) RETURNS boolean AS ...; +CREATE DOMAIN mytext AS text CHECK (...); +CREATE FUNCTION mytext_eq_text(mytext, text) RETURNS boolean AS ...; CREATE OPERATOR = (procedure=mytext_eq_text, leftarg=mytext, rightarg=text); CREATE TABLE mytable (val mytext); diff --git a/doc/src/sgml/xfunc.sgml b/doc/src/sgml/xfunc.sgml index 04bf919b343..aefaa4d59b0 100644 --- a/doc/src/sgml/xfunc.sgml +++ b/doc/src/sgml/xfunc.sgml @@ -167,7 +167,7 @@ Alternatively, an SQL function can be declared to return a set (that is, multiple rows) by specifying the function's return type as SETOF sometype, or equivalently by declaring it as - RETURNS TABLE(columns). In this case + RETURNS TABLE (columns). In this case all rows of the last query's result are returned. Further details appear below. @@ -378,7 +378,7 @@ SELECT add_em(1, 2) AS answer; bank account: -CREATE FUNCTION tf1 (accountno integer, debit numeric) RETURNS numeric AS $$ +CREATE FUNCTION tf1(accountno integer, debit numeric) RETURNS numeric AS $$ UPDATE bank SET balance = balance - debit WHERE accountno = tf1.accountno; @@ -409,7 +409,7 @@ SELECT tf1(17, 100.0); is: -CREATE FUNCTION tf1 (accountno integer, debit numeric) RETURNS numeric AS $$ +CREATE FUNCTION tf1(accountno integer, debit numeric) RETURNS numeric AS $$ UPDATE bank SET balance = balance - debit WHERE accountno = tf1.accountno; @@ -421,7 +421,7 @@ $$ LANGUAGE SQL; The same thing could be done in one command using RETURNING: -CREATE FUNCTION tf1 (accountno integer, debit numeric) RETURNS numeric AS $$ +CREATE FUNCTION tf1(accountno integer, debit numeric) RETURNS numeric AS $$ UPDATE bank SET balance = balance - debit WHERE accountno = tf1.accountno @@ -683,7 +683,7 @@ SELECT getname(new_emp()); with output parameters, as in this example: -CREATE FUNCTION add_em (IN x int, IN y int, OUT sum int) +CREATE FUNCTION add_em(IN x int, IN y int, OUT sum int) AS 'SELECT x + y' LANGUAGE SQL; @@ -700,7 +700,7 @@ SELECT add_em(3,7); functions that return several columns. For example, -CREATE FUNCTION sum_n_product (x int, y int, OUT sum int, OUT product int) +CREATE FUNCTION sum_n_product(x int, y int, OUT sum int, OUT product int) AS 'SELECT x + y, x * y' LANGUAGE SQL; @@ -718,7 +718,7 @@ LANGUAGE SQL; CREATE TYPE sum_prod AS (sum int, product int); -CREATE FUNCTION sum_n_product (int, int) RETURNS sum_prod +CREATE FUNCTION sum_n_product(int, int) RETURNS sum_prod AS 'SELECT $1 + $2, $1 * $2' LANGUAGE SQL; @@ -771,7 +771,7 @@ DROP FUNCTION sum_n_product (int, int); For example, the bank account debiting routine from earlier could be written like this: -CREATE PROCEDURE tp1 (accountno integer, debit numeric, OUT new_balance numeric) AS $$ +CREATE PROCEDURE tp1(accountno integer, debit numeric, OUT new_balance numeric) AS $$ UPDATE bank SET balance = balance - debit WHERE accountno = tp1.accountno @@ -1044,7 +1044,7 @@ SELECT * FROM getfoo(1) AS t1; CREATE TABLE tab (y int, z int); INSERT INTO tab VALUES (1, 2), (3, 4), (5, 6), (7, 8); -CREATE FUNCTION sum_n_product_with_tab (x int, OUT sum int, OUT product int) +CREATE FUNCTION sum_n_product_with_tab(x int, OUT sum int, OUT product int) RETURNS SETOF record AS $$ SELECT $1 + tab.y, $1 * tab.y FROM tab; @@ -1177,7 +1177,7 @@ SELECT x, g FROM tab, LATERAL generate_series(1,5) AS g; If there is more than one set-returning function in the query's select list, the behavior is similar to what you get from putting the functions - into a single LATERAL ROWS FROM( ... ) FROM-clause + into a single LATERAL ROWS FROM ( ... ) FROM-clause item. For each row from the underlying query, there is an output row using the first result from each function, then an output row using the second result, and so on. If some of the set-returning functions @@ -1193,7 +1193,7 @@ SELECT x, g FROM tab, LATERAL generate_series(1,5) AS g; Set-returning functions can be nested in a select list, although that is not allowed in FROM-clause items. In such cases, each level of nesting is treated separately, as though it were - a separate LATERAL ROWS FROM( ... ) item. For example, in + a separate LATERAL ROWS FROM ( ... ) item. For example, in SELECT srf1(srf2(x), srf3(y)), srf4(srf5(z)) FROM tab; @@ -1286,7 +1286,7 @@ SELECT x, case_generate_series(y > 0, 1, z, 5) FROM tab; There is another way to declare a function as returning a set, which is to use the syntax - RETURNS TABLE(columns). + RETURNS TABLE (columns). This is equivalent to using one or more OUT parameters plus marking the function as returning SETOF record (or SETOF a single output parameter's type, as appropriate). @@ -1299,8 +1299,8 @@ SELECT x, case_generate_series(y > 0, 1, z, 5) FROM tab; done this way: -CREATE FUNCTION sum_n_product_with_tab (x int) -RETURNS TABLE(sum int, product int) AS $$ +CREATE FUNCTION sum_n_product_with_tab(x int) +RETURNS TABLE (sum int, product int) AS $$ SELECT $1 + tab.y, $1 * tab.y FROM tab; $$ LANGUAGE SQL; @@ -1408,7 +1408,7 @@ DETAIL: A result of type anyelement requires at least one input of type anyelem Polymorphism can be used with functions that have output arguments. For example: -CREATE FUNCTION dup (f1 anyelement, OUT f2 anyelement, OUT f3 anyarray) +CREATE FUNCTION dup(f1 anyelement, OUT f2 anyelement, OUT f3 anyarray) AS 'select $1, array[$1,$1]' LANGUAGE SQL; SELECT * FROM dup(22); @@ -1423,7 +1423,7 @@ SELECT * FROM dup(22); Polymorphism can also be used with variadic functions. For example: -CREATE FUNCTION anyleast (VARIADIC anyarray) RETURNS anyelement AS $$ +CREATE FUNCTION anyleast(VARIADIC anyarray) RETURNS anyelement AS $$ SELECT min($1[i]) FROM generate_subscripts($1, 1) g(i); $$ LANGUAGE SQL; @@ -1486,7 +1486,7 @@ SELECT anyleast('abc'::text, 'ABC' COLLATE "C"); This version of anyleast would always use en_US locale to compare strings: -CREATE FUNCTION anyleast (VARIADIC anyarray) RETURNS anyelement AS $$ +CREATE FUNCTION anyleast(VARIADIC anyarray) RETURNS anyelement AS $$ SELECT min($1[i] COLLATE "en_US") FROM generate_subscripts($1, 1) g(i); $$ LANGUAGE SQL; -- 2.51.2