1
0
mirror of https://github.com/postgres/postgres.git synced 2025-06-13 07:41:39 +03:00

New blood and fresh air for tutorial

This commit is contained in:
Peter Eisentraut
2001-09-02 23:27:50 +00:00
parent 5608f13028
commit 60ce9e9279
9 changed files with 1352 additions and 1141 deletions

View File

@ -1,19 +1,18 @@
---------------------------------------------------------------------------
--
-- advanced.sql-
-- more POSTGRES SQL features. (These are not part of the SQL-92
-- standard.)
-- Tutorial on advanced more PostgreSQL features
--
--
-- Copyright (c) 1994, Regents of the University of California
--
-- $Id: advanced.source,v 1.3 1999/07/08 15:28:51 momjian Exp $
-- $Id: advanced.source,v 1.4 2001/09/02 23:27:50 petere Exp $
--
---------------------------------------------------------------------------
-----------------------------
-- Inheritance:
-- a table can inherit from zero or more tables. A query can reference
-- S table can inherit from zero or more tables. A query can reference
-- either all rows of a table or all rows of a table plus all of its
-- descendants.
-----------------------------
@ -31,7 +30,7 @@ CREATE TABLE capitals (
state char(2)
) INHERITS (cities);
-- now, let's populate the tables
-- Now, let's populate the tables.
INSERT INTO cities VALUES ('San Francisco', 7.24E+5, 63);
INSERT INTO cities VALUES ('Las Vegas', 2.583E+5, 2174);
INSERT INTO cities VALUES ('Mariposa', 1200, 1953);
@ -56,72 +55,6 @@ FROM cities* c
WHERE c.altitude > 500;
-----------------------------
-- Time Travel:
-- this feature allows you to run historical queries.
-- removed for v6.3, but possible using triggers.
-- see contrib/spi/README for more information.
-----------------------------
-- first, let's make some changes to the cities table (suppose Mariposa's
-- population grows 10% this year)
-- UPDATE cities
-- SET population = population * 1.1
-- WHERE name = 'Mariposa';
-- the default time is the current time ('now'):
-- SELECT * FROM cities WHERE name = 'Mariposa';
-- we can also retrieve the population of Mariposa ever has. ('epoch' is the
-- earliest time representable by the system)
-- SELECT name, population
-- FROM cities['epoch', 'now'] -- can be abbreviated to cities[,]
-- WHERE name = 'Mariposa';
----------------------
-- Arrays:
-- attributes can be arrays of base types or user-defined types
----------------------
CREATE TABLE sal_emp (
name text,
pay_by_quarter int4[],
schedule text[][]
);
-- insert instances with array attributes. Note the use of braces
INSERT INTO sal_emp VALUES (
'Bill',
'{10000,10000,10000,10000}',
'{{"meeting", "lunch"}, {}}');
INSERT INTO sal_emp VALUES (
'Carol',
'{20000,25000,25000,25000}',
'{{"talk", "consult"}, {"meeting"}}');
----------------------
-- queries on array attributes
----------------------
SELECT name FROM sal_emp WHERE
sal_emp.pay_by_quarter[1] <> sal_emp.pay_by_quarter[2];
-- retrieve third quarter pay of all employees
SELECT sal_emp.pay_by_quarter[3] FROM sal_emp;
-- select subarrays
SELECT sal_emp.schedule[1:2][1:1] FROM sal_emp WHERE
sal_emp.name = 'Bill';
-- clean up (you must remove the children first)
DROP TABLE sal_emp;
DROP TABLE capitals;
DROP TABLE cities;

View File

@ -6,22 +6,22 @@
--
-- Copyright (c) 1994, Andrew Yu, University of California
--
-- $Id: basics.source,v 1.3 1999/07/08 15:27:01 momjian Exp $
-- $Id: basics.source,v 1.4 2001/09/02 23:27:50 petere Exp $
--
---------------------------------------------------------------------------
-----------------------------
-- Creating a table:
-- a CREATE TABLE is used to create base tables. POSTGRES SQL has
-- its own set of built-in types. (Note that keywords are case-
-- insensitive but identifiers are case-sensitive.)
-- Creating a New Table:
-- A CREATE TABLE is used to create base tables. PostgreSQL has
-- its own set of built-in types. (Note that SQL is case-
-- insensitive.)
-----------------------------
CREATE TABLE weather (
city varchar(80),
temp_lo int, -- low temperature
temp_hi int, -- high temperature
prcp float8, -- precipitation
prcp real, -- precipitation
date date
);
@ -30,98 +30,105 @@ CREATE TABLE cities (
location point
);
-----------------------------
-- Inserting data:
-- an INSERT statement is used to insert a new row into a table. There
-- Populating a Table With Rows:
-- An INSERT statement is used to insert a new row into a table. There
-- are several ways you can specify what columns the data should go to.
-----------------------------
-- 1. the simplest case is when the list of value correspond to the order of
-- 1. The simplest case is when the list of value correspond to the order of
-- the columns specified in CREATE TABLE.
INSERT INTO weather
VALUES ('San Francisco', 46, 50, 0.25, '11/27/1994');
VALUES ('San Francisco', 46, 50, 0.25, '1994-11-27');
INSERT INTO cities
VALUES ('San Francisco', '(-194.0, 53.0)');
VALUES ('San Francisco', '(-194.0, 53.0)');
-- 2. you can also specify what column the values correspond to. (The columns
-- can be specified in any order. You may also omit any number of columns.
-- eg. unknown precipitation below)
-- 2. You can also specify what column the values correspond to. (The columns
-- can be specified in any order. You may also omit any number of columns,
-- e.g., unknown precipitation below.
INSERT INTO weather (city, temp_lo, temp_hi, prcp, date)
VALUES ('San Francisco', 43, 57, 0.0, '11/29/1994');
VALUES ('San Francisco', 43, 57, 0.0, '1994-11-29');
INSERT INTO weather (date, city, temp_hi, temp_lo)
VALUES ('11/29/1994', 'Hayward', 54, 37);
VALUES ('1994-11-29', 'Hayward', 54, 37);
-----------------------------
-- Retrieving data:
-- a SELECT statement is used for retrieving data. The basic syntax is
-- SELECT columns FROM tables WHERE predicates
-- Querying a Table:
-- A SELECT statement is used for retrieving data. The basic syntax is
-- SELECT columns FROM tables WHERE predicates.
-----------------------------
-- a simple one would be
-- A simple one would be:
SELECT * FROM weather;
-- you may also specify expressions in the target list (the 'AS column'
-- specifies the column name of the result. It is optional.)
-- You may also specify expressions in the target list. (The 'AS column'
-- specifies the column name of the result. It is optional.)
SELECT city, (temp_hi+temp_lo)/2 AS temp_avg, date FROM weather;
-- if you want to retrieve rows that satisfy certain condition (ie. a
-- restriction), specify the condition in WHERE. The following retrieves
-- If you want to retrieve rows that satisfy certain condition (i.e., a
-- restriction), specify the condition in WHERE. The following retrieves
-- the weather of San Francisco on rainy days.
SELECT *
FROM weather
WHERE city = 'San Francisco'
and prcp > 0.0;
FROM weather
WHERE city = 'San Francisco'
AND prcp > 0.0;
-- here is a more complicated one. Duplicates are removed when DISTINCT is
-- specified. ORDER BY specifies the column to sort on. (Just to make sure the
-- Here is a more complicated one. Duplicates are removed when DISTINCT is
-- specified. ORDER BY specifies the column to sort on. (Just to make sure the
-- following won't confuse you, DISTINCT and ORDER BY can be used separately.)
SELECT DISTINCT city
FROM weather
ORDER BY city;
FROM weather
ORDER BY city;
-----------------------------
-- Retrieving data into other classes:
-- a SELECT ... INTO statement can be used to retrieve data into
-- another class.
-----------------------------
SELECT * INTO TABLE mytemp
FROM weather
WHERE city = 'San Francisco'
and prcp > 0.0;
SELECT * from mytemp;
-----------------------------
-- Aggregates
-----------------------------
SELECT max(temp_lo)
FROM weather;
-- Aggregate with GROUP BY
SELECT city, max(temp_lo)
FROM weather
GROUP BY city;
-----------------------------
-- Joining tables:
-- Joins Between Tables:
-- queries can access multiple tables at once or access the same table
-- in such a way that multiple instances of the table are being processed
-- at the same time.
-----------------------------
-- suppose we want to find all the records that are in the temperature range
-- of other records. W1 and W2 are aliases for weather.
-- The following joins the weather table and the cities table.
SELECT *
FROM weather, cities
WHERE city = name;
-- This prevents a duplicate city name column:
SELECT city, temp_lo, temp_hi, prcp, date, location
FROM weather, cities
WHERE city = name;
-- since the column names are all different, we don't have to specify the
-- table name. If you want to be clear, you can do the following. They give
-- identical results, of course.
SELECT weather.city, weather.temp_lo, weather.temp_hi, weather.prcp, weather.date, cities.location
FROM weather, cities
WHERE cities.name = weather.city;
-- JOIN syntax
SELECT *
FROM weather JOIN cities ON (weather.city = cities.name);
-- Outer join
SELECT *
FROM weather LEFT OUTER JOIN cities ON (weather.city = cities.name);
-- Suppose we want to find all the records that are in the temperature range
-- of other records. W1 and W2 are aliases for weather.
SELECT W1.city, W1.temp_lo, W1.temp_hi,
W2.city, W2.temp_lo, W2.temp_hi
@ -129,60 +136,69 @@ FROM weather W1, weather W2
WHERE W1.temp_lo < W2.temp_lo
and W1.temp_hi > W2.temp_hi;
-- let's join two tables. The following joins the weather table
-- and the cities table.
SELECT city, location, prcp, date
FROM weather, cities
WHERE name = city;
-- since the column names are all different, we don't have to specify the
-- table name. If you want to be clear, you can do the following. They give
-- identical results, of course.
SELECT w.city, c.location, w.prcp, w.date
FROM weather w, cities c
WHERE c.name = w.city;
-----------------------------
-- Updating data:
-- an UPDATE statement is used for updating data.
-- Aggregate Functions
-----------------------------
-- suppose you discover the temperature readings are all off by 2 degrees as
SELECT max(temp_lo)
FROM weather;
SELECT city FROM weather
WHERE temp_lo = (SELECT max(temp_lo) FROM weather);
-- Aggregate with GROUP BY
SELECT city, max(temp_lo)
FROM weather
GROUP BY city;
-- ... and HAVING
SELECT city, max(temp_lo)
FROM weather
GROUP BY city
HAVING max(temp_lo) < 40;
-----------------------------
-- Updates:
-- An UPDATE statement is used for updating data.
-----------------------------
-- Suppose you discover the temperature readings are all off by 2 degrees as
-- of Nov 28, you may update the data as follow:
UPDATE weather
SET temp_hi = temp_hi - 2, temp_lo = temp_lo - 2
WHERE date > '11/28/1994';
SET temp_hi = temp_hi - 2, temp_lo = temp_lo - 2
WHERE date > '1994-11-28';
SELECT * from weather;
SELECT * FROM weather;
-----------------------------
-- Deleting data:
-- a DELETE statement is used for deleting rows from a table.
-- Deletions:
-- A DELETE statement is used for deleting rows from a table.
-----------------------------
-- suppose you are no longer interested in the weather of Hayward, you can
-- do the following to delete those rows from the table
-- Suppose you are no longer interested in the weather of Hayward, then you can
-- do the following to delete those rows from the table.
DELETE FROM weather WHERE city = 'Hayward';
SELECT * from weather;
SELECT * FROM weather;
-- you can also delete all the rows in a table by doing the following. (This
-- You can also delete all the rows in a table by doing the following. (This
-- is different from DROP TABLE which removes the table in addition to the
-- removing the rows.)
DELETE FROM weather;
SELECT * from weather;
SELECT * FROM weather;
-----------------------------
-- Removing the tables:
-- DROP TABLE is used to remove tables. After you have done this, you
-- DROP TABLE is used to remove tables. After you have done this, you
-- can no longer use those tables.
-----------------------------
DROP TABLE weather, cities, mytemp;
DROP TABLE weather, cities;