MacLochlainns Weblog

Michael McLaughlin's Technical Blog

Site Admin

PostgreSQL Composites

without comments

PostgreSQL like Oracle supports record data types but unlike Oracle, PostgreSQL doesn’t support collections of record data types. Here’s an example of how to define a PostgreSQL composite data type, and how to use it as a column’s data type.

CREATE TYPE address_type AS
( street_address  VARCHAR
, city            VARCHAR
, state           VARCHAR
, zip_code        VARCHAR );

Then, you define an ADDRESS table, like:

CREATE TABLE address
( address_id      SERIAL
, address_struct  ADDRESS_TYPE );

You can now insert rows like:

-- Insert the first row.
INSERT INTO address
( address_struct )
VALUES
(('52 Hubble Street','Lexington','KY','40511-1225'));
 
-- Insert the second row.
INSERT INTO address
( address_struct )
VALUES
(('54 Hubble Street','Lexington','KY','40511-1225'));

Then, you can query them like this:

SELECT * FROM address;

It returns:

 address_id |                address_struct
------------+----------------------------------------------
          1 | ("52 Hubble Street",Lexington,KY,40511-1225)
          2 | ("54 Hubble Street",Lexington,KY,40511-1225)
(2 rows)

You must use parentheses around the ADDRESS_STRUCT column to query individual items, like:

SELECT   address_id
,       (address_struct).street_address
,       (address_struct).city
,       (address_struct).state
,       (address_struct).zip_code
FROM     address;

It returns output like a table:

 address_id |  street_address  |   city    | state |  zip_code
------------+------------------+-----------+-------+------------
          1 | 52 Hubble Street | Lexington | KY    | 40511-1225
          2 | 54 Hubble Street | Lexington | KY    | 40511-1225
(2 rows)

While you can define a table that holds an array of a composite type, there’s no syntax that appears to work with an array of a composite type. I hope this helps those interested in implementing record structures in PostgreSQL.

Written by maclochlainn

March 16th, 2015 at 2:02 am