Thread: Postgresql 8.3X supports Arrays of Composite Types?

Postgresql 8.3X supports Arrays of Composite Types?

From
Robson Fidalgo
Date:

Hello,
I am using postgresql 8.3X and I created a table (see example below) that has an attribute that is an Array of a Composite Type (ROW). However, I do not know how can I insert a record in this table.

Well, I've searched the mailing lists and have found little said about the OR features. In postgres 8.3X on-line documentation (http://www.postgresql.org/docs/8.3/static/arrays.html) I found "Arrays of any built-in or user-defined base type, enum type, or composite type can be created", however there is no example that explains how can I do an insert into an attribute that is an Array of Composite Type. Considering the example below, "persons have N phones" I create (with success) the Person table with an array of phones, but I have not success with Insert values. There is some one that can help me?

Thanks in advances,

Robson

Example:

CREATE table phone (
  cod varchar,
  num varchar);

CREATE TABLE person (
  name varchar,
  telephone phone[]);

Until here is everything ok, but I have not success with insert values, then I tried:

1)insert into person values ('Joe', '{("1","1111"),("2","2222") }');
2)insert into person values ('Joe', array[('1','1111'),('2','2222')]);
3)insert into person values ('Joe', array[row('1','1111'),row('2','2222')]);
4)insert into person values ('Joe', _phone[phone('1','1111'),phone('2','2222')]);**
** considering _phone = name of array type (automatically created by postgres) and phone = name of composite type (also automatically created by postgres)

Re: Postgresql 8.3X supports Arrays of Composite Types?

From
Tom Lane
Date:
Robson Fidalgo <rdnf@cin.ufpe.br> writes:
> I am using postgresql 8.3X and I created a table (see example below) that
> has an attribute that is an Array of a Composite Type (ROW). However, I do
> not know how can I insert a record in this table.

You need some explicit casts so that the array[] construct is seen to
have the right type, eg

insert into person values ('Joe', array[row('1','1111')::phone, row('2','2222')::phone]);

            regards, tom lane

Re: Postgresql 8.3X supports Arrays of Composite Types?

From
David Fetter
Date:
On Sun, Apr 19, 2009 at 06:03:26PM -0300, Robson Fidalgo wrote:
> Hello,
> I am using postgresql 8.3X and I created a table (see example below)
> that has an attribute that is an Array of a Composite Type (ROW).
> However, I do not know how can I insert a record in this table.

You want a normalized table anyhow.  If you want something
denormalized, use a view.

> Example:
>
> CREATE table phone (
>   cod varchar,
>   num varchar);
>
> CREATE TABLE person (
>   name varchar,
>   telephone phone[]);

This is better as:

CREATE TABLE phone (
    cod VARCHAR,
    num VARCHAR,
    PRIMARY KEY(cod, num)
);

CREATE TABLE person (
    name varchar,
    PRIMARY KEY(name)
)

CREATE TABLE person_phone (
    name VARCHAR NOT NULL REFERENCES person(name),
    cod VARCHAR,
    num VARCHAR,
    FOREIGN KEY(cod, num) REFERENCES phone(cod, num),
    PRIMARY KEY(name, cod, num)
);

Cheers,
David.
--
David Fetter <david@fetter.org> http://fetter.org/
Phone: +1 415 235 3778  AIM: dfetter666  Yahoo!: dfetter
Skype: davidfetter      XMPP: david.fetter@gmail.com

Remember to vote!
Consider donating to Postgres: http://www.postgresql.org/about/donate

Re: [DOCS] Postgresql 8.3X supports Arrays of Composite Types?

From
Robson Fidalgo
Date:


On Mon, Apr 20, 2009 at 8:13 AM, Robson Fidalgo <rdnf@cin.ufpe.br> wrote:

Hi David,

 

Thanks for your help, but I want a relational-object solution. The solution presented by Tom Lane (Thanks Tom!!!!) runs very well and it is a relational-object implementation (I suggest put a similar example in postgresql 8.3X documentation).

 

Cheers,

Robson.


On Sun, Apr 19, 2009 at 8:56 PM, David Fetter <david@fetter.org> wrote:
On Sun, Apr 19, 2009 at 06:03:26PM -0300, Robson Fidalgo wrote:
> Hello,
> I am using postgresql 8.3X and I created a table (see example below)
> that has an attribute that is an Array of a Composite Type (ROW).
> However, I do not know how can I insert a record in this table.

You want a normalized table anyhow.  If you want something
denormalized, use a view.

> Example:
>
> CREATE table phone (
>   cod varchar,
>   num varchar);
>
> CREATE TABLE person (
>   name varchar,
>   telephone phone[]);

This is better as:

CREATE TABLE phone (
   cod VARCHAR,
   num VARCHAR,
   PRIMARY KEY(cod, num)
);

CREATE TABLE person (
   name varchar,
   PRIMARY KEY(name)
)

CREATE TABLE person_phone (
   name VARCHAR NOT NULL REFERENCES person(name),
   cod VARCHAR,
   num VARCHAR,
   FOREIGN KEY(cod, num) REFERENCES phone(cod, num),
   PRIMARY KEY(name, cod, num)
);

Cheers,
David.
--
David Fetter <david@fetter.org> http://fetter.org/
Phone: +1 415 235 3778  AIM: dfetter666  Yahoo!: dfetter
Skype: davidfetter      XMPP: david.fetter@gmail.com

Remember to vote!
Consider donating to Postgres: http://www.postgresql.org/about/donate

--
Sent via pgsql-docs mailing list (pgsql-docs@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-docs


Re: [DOCS] Postgresql 8.3X supports Arrays of Composite Types?

From
Robson Fidalgo
Date:

Hi David,

 

Thanks for your help, but I want a relational-object solution. The solution presented by Tom Lane (Thanks Tom!!!!) runs very well and it is a relational-object implementation (I suggest put a similar example in postgresql 8.3X documentation).

 

Cheers,

Robson.


On Sun, Apr 19, 2009 at 8:56 PM, David Fetter <david@fetter.org> wrote:
On Sun, Apr 19, 2009 at 06:03:26PM -0300, Robson Fidalgo wrote:
> Hello,
> I am using postgresql 8.3X and I created a table (see example below)
> that has an attribute that is an Array of a Composite Type (ROW).
> However, I do not know how can I insert a record in this table.

You want a normalized table anyhow.  If you want something
denormalized, use a view.

> Example:
>
> CREATE table phone (
>   cod varchar,
>   num varchar);
>
> CREATE TABLE person (
>   name varchar,
>   telephone phone[]);

This is better as:

CREATE TABLE phone (
   cod VARCHAR,
   num VARCHAR,
   PRIMARY KEY(cod, num)
);

CREATE TABLE person (
   name varchar,
   PRIMARY KEY(name)
)

CREATE TABLE person_phone (
   name VARCHAR NOT NULL REFERENCES person(name),
   cod VARCHAR,
   num VARCHAR,
   FOREIGN KEY(cod, num) REFERENCES phone(cod, num),
   PRIMARY KEY(name, cod, num)
);

Cheers,
David.
--
David Fetter <david@fetter.org> http://fetter.org/
Phone: +1 415 235 3778  AIM: dfetter666  Yahoo!: dfetter
Skype: davidfetter      XMPP: david.fetter@gmail.com

Remember to vote!
Consider donating to Postgres: http://www.postgresql.org/about/donate

--
Sent via pgsql-docs mailing list (pgsql-docs@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-docs

Re: [DOCS] Postgresql 8.3X supports Arrays of Composite Types?

From
David Fetter
Date:
On Mon, Apr 20, 2009 at 08:13:15AM -0300, Robson Fidalgo wrote:
> Hi David,
>
> Thanks for your help, but I want a relational-object solution.

You can have one without denormalizing.  Just use VIEWs and rewrite
RULEs for INSERTs, UPDATEs and DELETEs on them.

> The solution presented by Tom Lane (Thanks Tom!!!!) runs very well
> and it is a relational-object implementation (I suggest put a
> similar example in postgresql 8.3X documentation).

The docs already contain an example:

http://www.postgresql.org/docs/current/static/rules-update.html

There are excellent reasons not to encourage people to do only half
the job.  One part, the smaller part, is presenting an interface which
one part of your OO code can talk to.  The other part, and the much
larger one, is having a well-indexed, normalized data store
underneath.

Example: Under the store-the-compound system you're proposing, how do
you find all the people who have a common prefix?  Answer: Normalize.
If you need that answer quickly, you're looking at down time and DDL
changes.  The questions you ask about the data are impossible to know
in advance, so normalized data helps you deal with that.

Cheers,
David.
--
David Fetter <david@fetter.org> http://fetter.org/
Phone: +1 415 235 3778  AIM: dfetter666  Yahoo!: dfetter
Skype: davidfetter      XMPP: david.fetter@gmail.com

Remember to vote!
Consider donating to Postgres: http://www.postgresql.org/about/donate

Re: Postgresql 8.3X supports Arrays of Composite Types?

From
Merlin Moncure
Date:
On Sun, Apr 19, 2009 at 5:03 PM, Robson Fidalgo <rdnf@cin.ufpe.br> wrote:
> Until here is everything ok, but I have not success with insert values, then
> I tried:
>
> 1)insert into person values ('Joe', '{("1","1111"),("2","2222") }');
> 2)insert into person values ('Joe', array[('1','1111'),('2','2222')]);
> 3)insert into person values ('Joe', array[row('1','1111'),row('2','2222')]);
> 4)insert into person values ('Joe',
> _phone[phone('1','1111'),phone('2','2222')]);**
> ** considering _phone = name of array type (automatically created by
> postgres) and phone = name of composite type (also automatically created by
> postgres)

I agree with David -- arrays of composites should not be used in table
definitions.  There are exceptions, but you have to be very cautious.
The phone number composite is basically ok, but I'd advise dropping
the array minimum.  Here are the basic problems:

*) constraint checking vs. array of composites is problematic
*) updating a specific field of a specific composite is not really
possible...you have to build a complete new composite array and update
the table with it.
*) searching (who has a phone number x?) is a problem

Imagine a client changes one of his/her phone numbers and compare the
sql you would have to write doing it the classic way vs. your way.

As David noted, if you like the composite format in the presentation
of data, you can trivially do this in view.  There may be reasons to
do this -- the advantages of composite are convenience in passing data
to/from functions and nesting data returned to the client.  There is
no disadvantage of nesting data 'in query' -- that's how I do it and
it works very well.

There are a couple of exceptions to the 'no arrays in table'.  You may
have a lot of static data (think float[]) that you are doing numerical
analysis on the client for example.  It only ever gets
inserted/selected/deleted in bulk and never updated.  There are other
exceptions, but they are rare. Usually it's better doing it the 'sql
way'

merlin