Advanced <productname>Postgres</productname> <acronym>SQL</acronym> Features Having covered the basics of using Postgres SQL to access your data, we will now discuss those features of Postgres that distinguish it from conventional data managers. These features include inheritance, time travel and non-atomic data values (array- and set-valued attributes). Examples in this section can also be found in advance.sql in the tutorial directory. (Refer to for how to use it.) Inheritance Let's create two tables. The capitals table contains state capitals that are also cities. Naturally, the capitals table should inherit from cities. CREATE TABLE cities ( name text, population real, altitude int -- (in ft) ); CREATE TABLE capitals ( state char(2) ) INHERITS (cities); In this case, a row of capitals inherits all columns (name, population, and altitude) from its parent, cities. The type of the column name is text, a native Postgres type for variable length ASCII strings. The type of the column population is real, a type for single precision floating point numbers. State capitals have an extra column, state, that shows their state. In Postgres, a table can inherit from zero or more other tables, and a query can reference either all rows of a table or all rows of a tables plus all of its descendants. The inheritance hierarchy is a directed acyclic graph. For example, the following query finds the names of all cities, including state capitals, that are located at an altitude over 500ft: SELECT name, altitude FROM cities WHERE altitude > 500; which returns: +----------+----------+ |name | altitude | +----------+----------+ |Las Vegas | 2174 | +----------+----------+ |Mariposa | 1953 | +----------+----------+ |Madison | 845 | +----------+----------+ On the other hand, the following query finds all the cities that are not state capitals and are situated at an altitude of 500ft or higher: SELECT name, altitude FROM ONLY cities WHERE altitude > 500; +----------+----------+ |name | altitude | +----------+----------+ |Las Vegas | 2174 | +----------+----------+ |Mariposa | 1953 | +----------+----------+ Here the ONLY before cities indicates that the query should be run over only the cities table, and not tables below cities in the inheritance hierarchy. Many of the commands that we have already discussed -- SELECT, UPDATE and DELETE -- support this ONLY notation. Deprecated In previous versions of Postgres, the default was not to get access to child tables. This was found to be error prone and is also in violation of SQL99. Under the old syntax, to get the sub-tables you append "*" to the table name. For example SELECT * from cities*; You can still explicitly specify scanning child tables by appending "*", as well as explicitly specify not scanning child tables by writing ONLY. But beginning in version 7.1, the default behavior for an undecorated table name is to scan its child tables too, whereas before the default was not to do so. To get the old default behavior, set the configuration option SQL_Inheritance to off, e.g., SET SQL_Inheritance TO OFF; or add a line in your postgresql.conf file. Non-Atomic Values One of the tenets of the relational model is that the columns of a table are atomic. Postgres does not have this restriction; columns can themselves contain sub-values that can be accessed from the query language. For example, you can create columns that are arrays of base types. Arrays Postgres allows columns of a row to be defined as fixed-length or variable-length multi-dimensional arrays. Arrays of any base type or user-defined type can be created. To illustrate their use, we first create a table with arrays of base types. CREATE TABLE SAL_EMP ( name text, pay_by_quarter integer[], schedule text[][] ); The above query will create a table named SAL_EMP with a text string (name), a one-dimensional array of integer (pay_by_quarter), which represents the employee's salary by quarter and a two-dimensional array of text (schedule), which represents the employee's weekly schedule. Now we do some INSERTs; note that when appending to an array, we enclose the values within braces and separate them by commas. If you know C, this is not unlike the syntax for initializing structures. 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"}}'); By default, Postgres uses the "one-based" numbering convention for arrays -- that is, an array of n elements starts with array[1] and ends with array[n]. Now, we can run some queries on SAL_EMP. First, we show how to access a single element of an array at a time. This query retrieves the names of the employees whose pay changed in the second quarter: SELECT name FROM SAL_EMP WHERE SAL_EMP.pay_by_quarter[1] <> SAL_EMP.pay_by_quarter[2]; +------+ |name | +------+ |Carol | +------+ This query retrieves the third quarter pay of all employees: SELECT SAL_EMP.pay_by_quarter[3] FROM SAL_EMP; +---------------+ |pay_by_quarter | +---------------+ |10000 | +---------------+ |25000 | +---------------+ We can also access arbitrary slices of an array (subarrays) by specifying both lower and upper bounds for each subscript. This query retrieves the first item on Bill's schedule for the first two days of the week. SELECT SAL_EMP.schedule[1:2][1:1] FROM SAL_EMP WHERE SAL_EMP.name = 'Bill'; +-------------------+ |schedule | +-------------------+ |{{"meeting"},{""}} | +-------------------+ More Advanced Features Postgres has many features not touched upon in this tutorial introduction, which has been oriented toward newer users of SQL. These are discussed in more detail in both the User's and Programmer's Guides.