Thread: A form of inheritance with PostgreSQL
Hello.<br /><br /> I'm trying to figure out how to nicely implement a C++ class-like system with PostgreSQL. Consider thefollowing:<br /><br /> Tables Fruit, Apple, Orange<br /><br /> I want to design the foreign key scheme such that thereare relations between fruit and apple, and fruit and orange, that imply that apple is a fruit, and orange is a fruit.<br/><br /> I don't want to eliminate the existence of Apple and Orange tables, because there will be columns specificto both Apple and Orange; if I include these columns in Fruit, then if Fruit is an Orange, the Apple columns willbe needlessly present in Apple rows.<br /><br /> The different ways of implementing this scheme that I've thought of(some uglier than others):<br /><br /> - Have Fruit contain foreign keys to both Apple and Orange, and write a check constraintin Fruit specifying that exactly one of (Apple FK, Orange FK) needs to be non-null. The disadvantage of this methodis that it isn't exactly loosely coupled. For every other fruit type table I implemented I'd have to go back and adda foreign key in Fruit.<br /><br /> - Have a foreign key in Apple to Fruit, and in Orange to Fruit; then somehow createa constraint that imposes uniqueness on the union of foreign keys in both Apple and Orange. To figure out what typeof fruit a Fruit row is, run a query for foreign keys in Orange and Apple matching the primary key of Fruit. You'd alsowant to somehow create a constraint that the result of this query should always return exactly one row (perhaps witha trigger?)<br /><br /> Any advice will be appreciated! As I'm relatively new to Postgre, I might need some help withthe actual implementation as well.<br /><br /> Thank you.<br /><br /> - Greg<br />
Greg Toombs wrote: > Hello. > > I'm trying to figure out how to nicely implement a C++ class-like system with > PostgreSQL. Consider the following: Don't do a lot of this myself, but I do know that there are several object-relational mappers that do this sort of stuff for you. Might be worth a bit of googling. -- Richard Huxton Archonet Ltd
> I want to design the foreign key scheme such that there are relationsbetween > fruit and apple, and fruit and orange, that imply that apple isa fruit, > and orange is a fruit. Sometime in the future, you will be able to achieve this beautifully and easily using postgresql's feature known as table-inheritance. Right now it can already support hierchey between different types of fruit, however it does not allow for foreign key relationships. However, I figured out a work-around using seperate a table for each entity of the heirchey. And then I rolled up these entities using views made update-able with the Postgresql rule system. Here is a link were I present how it is done. http://archives.postgresql.org/pgsql-general/2006-12/msg00913.php Let me know if you have any questions. Regards, Richard Broersma Jr.
Just a little example of what I've been using on version 8.0.3 with total satisfaction.
CREATE TABLE "public"."tblMovementDetails" (
"ID" INTEGER NOT NULL,
"PlanningDetailID" INTEGER NOT NULL,
"MovementID" INTEGER NOT NULL,
"UserID" VARCHAR(5) NOT NULL,
"Number" INTEGER DEFAULT 0 NOT NULL,
"ChangeDate" DATE NOT NULL,
CONSTRAINT "PK_tblMovementDetails" PRIMARY KEY("ID")
) WITHOUT OIDS;
"ID" INTEGER NOT NULL,
"PlanningDetailID" INTEGER NOT NULL,
"MovementID" INTEGER NOT NULL,
"UserID" VARCHAR(5) NOT NULL,
"Number" INTEGER DEFAULT 0 NOT NULL,
"ChangeDate" DATE NOT NULL,
CONSTRAINT "PK_tblMovementDetails" PRIMARY KEY("ID")
) WITHOUT OIDS;
CREATE RULE "disallow_delete" AS ON DELETE TO "public"."tblMovementDetails"
DO INSTEAD NOTHING;
DO INSTEAD NOTHING;
CREATE RULE "disallow_insert" AS ON INSERT TO "public"."tblMovementDetails"
DO INSTEAD NOTHING;
DO INSTEAD NOTHING;
CREATE RULE "disallow_update" AS ON UPDATE TO "public"."tblMovementDetails"
DO INSTEAD NOTHING;
DO INSTEAD NOTHING;
CREATE TABLE "public"."tblDeliveryDetails" (
"InvoiceAmount" NUMERIC(8,2) DEFAULT 0 NOT NULL,
CONSTRAINT "PK_tblDeliveryDetails" PRIMARY KEY("ID"),
CONSTRAINT "CH_tblDeliveryDetails_InvoiceAmount" CHECK ("InvoiceAmount" >= (0)::numeric),
CONSTRAINT "CH_tblDeliveryDetails_Number" CHECK ("Number" >= 0),
CONSTRAINT "FK_tblDeliveryDetails_tblMovement" FOREIGN KEY ("MovementID")
REFERENCES "public"."tblDelivery"("ID")
ON DELETE NO ACTION
ON UPDATE NO ACTION
NOT DEFERRABLE,
CONSTRAINT "FK_tblDeliveryDetails_tblPlanningDetails" FOREIGN KEY ("PlanningDetailID")
REFERENCES "public"."tblPlanningDetails"("ID")
ON DELETE NO ACTION
ON UPDATE NO ACTION
NOT DEFERRABLE
) INHERITS ("public"."tblMovementDetails")
WITHOUT OIDS;
"InvoiceAmount" NUMERIC(8,2) DEFAULT 0 NOT NULL,
CONSTRAINT "PK_tblDeliveryDetails" PRIMARY KEY("ID"),
CONSTRAINT "CH_tblDeliveryDetails_InvoiceAmount" CHECK ("InvoiceAmount" >= (0)::numeric),
CONSTRAINT "CH_tblDeliveryDetails_Number" CHECK ("Number" >= 0),
CONSTRAINT "FK_tblDeliveryDetails_tblMovement" FOREIGN KEY ("MovementID")
REFERENCES "public"."tblDelivery"("ID")
ON DELETE NO ACTION
ON UPDATE NO ACTION
NOT DEFERRABLE,
CONSTRAINT "FK_tblDeliveryDetails_tblPlanningDetails" FOREIGN KEY ("PlanningDetailID")
REFERENCES "public"."tblPlanningDetails"("ID")
ON DELETE NO ACTION
ON UPDATE NO ACTION
NOT DEFERRABLE
) INHERITS ("public"."tblMovementDetails")
WITHOUT OIDS;
CREATE INDEX "IDX_tblDeliveryDetails_PlanningDetailID" ON "public"."tblDeliveryDetails"
USING btree ("PlanningDetailID");
USING btree ("PlanningDetailID");
CREATE TRIGGER "TRIG_tblDeliveryDetails_Archive" AFTER INSERT OR UPDATE OR DELETE
ON "public"."tblDeliveryDetails" FOR EACH ROW
EXECUTE PROCEDURE "public"."func_archive_delivery"();
ON "public"."tblDeliveryDetails" FOR EACH ROW
EXECUTE PROCEDURE "public"."func_archive_delivery"();
CREATE TRIGGER "TRIG_tblDeliveryDetails_ChangeDate" BEFORE INSERT OR UPDATE
ON "public"."tblDeliveryDetails" FOR EACH ROW
EXECUTE PROCEDURE "public"."func_set_changedate"();
ON "public"."tblDeliveryDetails" FOR EACH ROW
EXECUTE PROCEDURE "public"."func_set_changedate"();
CREATE RULE "get_pkey_on_insert" AS ON INSERT TO "public"."tblDeliveryDetails"
DO (SELECT currval('"tblDeliveryDetails_ID_seq"'::text) AS "ID", new."PlanningDetailID";);
DO (SELECT currval('"tblDeliveryDetails_ID_seq"'::text) AS "ID", new."PlanningDetailID";);
CREATE TABLE "public"."tblOrderDetails" (
"QuoteID" INTEGER NOT NULL,
CONSTRAINT "PK_tblOrderDetails" PRIMARY KEY("ID"),
CONSTRAINT "CH_tblOrderDetails_Number" CHECK ("Number" >= 0),
CONSTRAINT "FK_tblOrderDetails_tblMovement" FOREIGN KEY ("MovementID")
REFERENCES "public"."tblOrder"("ID")
ON DELETE NO ACTION
ON UPDATE NO ACTION
NOT DEFERRABLE,
CONSTRAINT "FK_tblOrderDetails_tblPlanningDetails" FOREIGN KEY ("PlanningDetailID")
REFERENCES "public"."tblPlanningDetails"("ID")
ON DELETE NO ACTION
ON UPDATE NO ACTION
NOT DEFERRABLE,
CONSTRAINT "FK_tblOrderDetails_tblQuote" FOREIGN KEY ("QuoteID")
REFERENCES "public"."tblQuote"("ID")
ON DELETE NO ACTION
ON UPDATE NO ACTION
NOT DEFERRABLE
) INHERITS ("public"."tblMovementDetails")
WITHOUT OIDS;
"QuoteID" INTEGER NOT NULL,
CONSTRAINT "PK_tblOrderDetails" PRIMARY KEY("ID"),
CONSTRAINT "CH_tblOrderDetails_Number" CHECK ("Number" >= 0),
CONSTRAINT "FK_tblOrderDetails_tblMovement" FOREIGN KEY ("MovementID")
REFERENCES "public"."tblOrder"("ID")
ON DELETE NO ACTION
ON UPDATE NO ACTION
NOT DEFERRABLE,
CONSTRAINT "FK_tblOrderDetails_tblPlanningDetails" FOREIGN KEY ("PlanningDetailID")
REFERENCES "public"."tblPlanningDetails"("ID")
ON DELETE NO ACTION
ON UPDATE NO ACTION
NOT DEFERRABLE,
CONSTRAINT "FK_tblOrderDetails_tblQuote" FOREIGN KEY ("QuoteID")
REFERENCES "public"."tblQuote"("ID")
ON DELETE NO ACTION
ON UPDATE NO ACTION
NOT DEFERRABLE
) INHERITS ("public"."tblMovementDetails")
WITHOUT OIDS;
CREATE TRIGGER "TRIG_tblOrderDetails_ChangeDate" BEFORE INSERT OR UPDATE
ON "public"."tblOrderDetails" FOR EACH ROW
EXECUTE PROCEDURE "public"."func_set_changedate"();
ON "public"."tblOrderDetails" FOR EACH ROW
EXECUTE PROCEDURE "public"."func_set_changedate"();
CREATE RULE "get_pkey_on_insert" AS ON INSERT TO "public"."tblOrderDetails"
DO (SELECT currval('"tblOrderDetails_ID_seq"'::text) AS "ID", new."PlanningDetailID";);
DO (SELECT currval('"tblOrderDetails_ID_seq"'::text) AS "ID", new."PlanningDetailID";);
CREATE TABLE "public"."tblSendingDetails" (
"HandlingCode" VARCHAR(10) DEFAULT ''::character varying,
CONSTRAINT "PK_tblSendingDetails" PRIMARY KEY("ID"),
CONSTRAINT "CH_tblSendingDetails_Number" CHECK ("Number" >= 0),
CONSTRAINT "FK_tblSendingDetails_tblMovement" FOREIGN KEY ("MovementID")
REFERENCES "public"."tblSending"("ID")
ON DELETE NO ACTION
ON UPDATE NO ACTION
NOT DEFERRABLE,
CONSTRAINT "FK_tblSendingDetails_tblPlanningDetails" FOREIGN KEY ("PlanningDetailID")
REFERENCES "public"."tblPlanningDetails"("ID")
ON DELETE NO ACTION
ON UPDATE NO ACTION
NOT DEFERRABLE
) INHERITS ("public"."tblMovementDetails")
WITHOUT OIDS;
"HandlingCode" VARCHAR(10) DEFAULT ''::character varying,
CONSTRAINT "PK_tblSendingDetails" PRIMARY KEY("ID"),
CONSTRAINT "CH_tblSendingDetails_Number" CHECK ("Number" >= 0),
CONSTRAINT "FK_tblSendingDetails_tblMovement" FOREIGN KEY ("MovementID")
REFERENCES "public"."tblSending"("ID")
ON DELETE NO ACTION
ON UPDATE NO ACTION
NOT DEFERRABLE,
CONSTRAINT "FK_tblSendingDetails_tblPlanningDetails" FOREIGN KEY ("PlanningDetailID")
REFERENCES "public"."tblPlanningDetails"("ID")
ON DELETE NO ACTION
ON UPDATE NO ACTION
NOT DEFERRABLE
) INHERITS ("public"."tblMovementDetails")
WITHOUT OIDS;
CREATE INDEX "IDX_tblSendingDetails_PlanningDetailID" ON "public"."tblSendingDetails"
USING btree ("PlanningDetailID");
USING btree ("PlanningDetailID");
CREATE TRIGGER "TRIG_tblSendingDetails_Archive" AFTER INSERT OR UPDATE OR DELETE
ON "public"."tblSendingDetails" FOR EACH ROW
EXECUTE PROCEDURE "public"."func_archive_sending"();
ON "public"."tblSendingDetails" FOR EACH ROW
EXECUTE PROCEDURE "public"."func_archive_sending"();
CREATE TRIGGER "TRIG_tblSendingDetails_ChangeDate" BEFORE INSERT OR UPDATE
ON "public"."tblSendingDetails" FOR EACH ROW
EXECUTE PROCEDURE "public"."func_set_changedate"();
ON "public"."tblSendingDetails" FOR EACH ROW
EXECUTE PROCEDURE "public"."func_set_changedate"();
CREATE RULE "get_pkey_on_insert" AS ON INSERT TO "public"."tblSendingDetails"
DO (SELECT currval('"tblSendingDetails_ID_seq"'::text) AS "ID", new."PlanningDetailID";);
>>> Greg Toombs <greg.toombs@bluebottle.com> 2007-03-08 19:01 >>>
Hello.
I'm trying to figure out how to nicely implement a C++ class-like system with PostgreSQL. Consider the following:
Tables Fruit, Apple, Orange
I want to design the foreign key scheme such that there are relations between fruit and apple, and fruit and orange, that imply that apple is a fruit, and orange is a fruit.
I don't want to eliminate the existence of Apple and Orange tables, because there will be columns specific to both Apple and Orange; if I include these columns in Fruit, then if Fruit is an Orange, the Apple columns will be needlessly present in Apple rows.
The different ways of implementing this scheme that I've thought of (some uglier than others):
- Have Fruit contain foreign keys to both Apple and Orange, and write a check constraint in Fruit specifying that exactly one of (Apple FK, Orange FK) needs to be non-null. The disadvantage of this method is that it isn't exactly loosely coupled. For every other fruit type table I implemented I'd have to go back and add a foreign key in Fruit.
- Have a foreign key in Apple to Fruit, and in Orange to Fruit; then somehow create a constraint that imposes uniqueness on the union of foreign keys in both Apple and Orange. To figure out what type of fruit a Fruit row is, run a query for foreign keys in Orange and Apple matching the primary key of Fruit. You'd also want to somehow create a constraint that the result of this query should always return exactly one row (perhaps with a trigger?)
Any advice will be appreciated! As I'm relatively new to Postgre, I might need some help with the actual implementation as well.
Thank you.
- Greg
DO (SELECT currval('"tblSendingDetails_ID_seq"'::text) AS "ID", new."PlanningDetailID";);
>>> Greg Toombs <greg.toombs@bluebottle.com> 2007-03-08 19:01 >>>
Hello.
I'm trying to figure out how to nicely implement a C++ class-like system with PostgreSQL. Consider the following:
Tables Fruit, Apple, Orange
I want to design the foreign key scheme such that there are relations between fruit and apple, and fruit and orange, that imply that apple is a fruit, and orange is a fruit.
I don't want to eliminate the existence of Apple and Orange tables, because there will be columns specific to both Apple and Orange; if I include these columns in Fruit, then if Fruit is an Orange, the Apple columns will be needlessly present in Apple rows.
The different ways of implementing this scheme that I've thought of (some uglier than others):
- Have Fruit contain foreign keys to both Apple and Orange, and write a check constraint in Fruit specifying that exactly one of (Apple FK, Orange FK) needs to be non-null. The disadvantage of this method is that it isn't exactly loosely coupled. For every other fruit type table I implemented I'd have to go back and add a foreign key in Fruit.
- Have a foreign key in Apple to Fruit, and in Orange to Fruit; then somehow create a constraint that imposes uniqueness on the union of foreign keys in both Apple and Orange. To figure out what type of fruit a Fruit row is, run a query for foreign keys in Orange and Apple matching the primary key of Fruit. You'd also want to somehow create a constraint that the result of this query should always return exactly one row (perhaps with a trigger?)
Any advice will be appreciated! As I'm relatively new to Postgre, I might need some help with the actual implementation as well.
Thank you.
- Greg
Hi Greg, While not in a C++ framework, you might find that it's not too hard to implement something similar in your system - It's called "Single Table Inheritance." References to the Ruby on Rails implementation here: http://wiki.rubyonrails.org/rails/pages/SingleTableInheritance It's based on Martin Fowler's Patterns of Enterprise Architecture book - please find references to his original patterns here: http://www.martinfowler.com/eaaCatalog/singleTableInheritance.html The key, I believe, is simply adding a "type" and a "parent_id" to the "class" table, so you can model all your types and their hierarchical relations. Fowler's diagram is pretty clear. I think then you would store the data in another table (or tables) and link into this inheritance structure to establish ancestry for any piece of data (some people try to store the data in this table too, but I think that's a mistake personally). If I understand what you're trying to do, you can use this design pattern in your application language to implement an inheritance scheme without any special database features (i.e. in a SQL-standard manner). I hope this is helpful, Steve At 12:28 AM 3/9/2007, pgsql-sql-owner@postgresql.org wrote: >Date: Thu, 08 Mar 2007 13:01:51 -0500 >From: Greg Toombs <greg.toombs@bluebottle.com> >To: pgsql-sql@postgresql.org >Subject: A form of inheritance with PostgreSQL >Message-ID: <45F04F8F.8030800@bluebottle.com> > > Hello. > >I'm trying to figure out how to nicely implement a C++ class-like >system >with PostgreSQL. Consider the following: > >Tables Fruit, Apple, Orange > >I want to design the foreign key scheme such that there are relations >between fruit and apple, and fruit and orange, that imply that apple >is a >fruit, and orange is a fruit. > >I don't want to eliminate the existence of Apple and Orange tables, >because there will be columns specific to both Apple and Orange; if I >include these columns in Fruit, then if Fruit is an Orange, the Apple >columns will be needlessly present in Apple rows. > >The different ways of implementing this scheme that I've thought of >(some >uglier than others): > >- Have Fruit contain foreign keys to both Apple and Orange, and write >a >check constraint in Fruit specifying that exactly one of (Apple FK, >Orange FK) needs to be non-null. The disadvantage of this method is >that >it isn't exactly loosely coupled. For every other fruit type table I >implemented I'd have to go back and add a foreign key in Fruit. > >- Have a foreign key in Apple to Fruit, and in Orange to Fruit; then >somehow create a constraint that imposes uniqueness on the union of >foreign keys in both Apple and Orange. To figure out what type of >fruit a >Fruit row is, run a query for foreign keys in Orange and Apple >matching >the primary key of Fruit. You'd also want to somehow create a >constraint >that the result of this query should always return exactly one row >(perhaps with a trigger?) > >Any advice will be appreciated! As I'm relatively new to Postgre, I >might >need some help with the actual implementation as well. > >Thank you. > >- Greg
Hello, and thank you to Steven and everyone else that submitted input on this issue.<br /><br /> After reading a few moremethods of doing things, I went with the simplest one, as 1. time is of the essence, and 2. I'm stuck with PostgreSQL7.1 on the server I have to develop for.<br /><br /> I set the primary key of the parent class to a serial. Childrenhave an integer column with constraints as the primary key and foreign key to the parent primary key column.<br /><br/> Thanks again,<br /><br /> - Greg<br /><br /> Steve Midgley wrote: <blockquote cite="mid20070309163840.66FFB9FBC7D@postgresql.org"type="cite">Hi Greg, <br /><br /> While not in a C++ framework, you mightfind that it's not too hard to implement something similar in your system - It's called "Single Table Inheritance."References to the Ruby on Rails implementation here: <br /><br /><a class="moz-txt-link-freetext" href="http://wiki.rubyonrails.org/rails/pages/SingleTableInheritance">http://wiki.rubyonrails.org/rails/pages/SingleTableInheritance</a><br /><br/> It's based on Martin Fowler's Patterns of Enterprise Architecture book - please find references to his original patternshere: <br /><br /><a class="moz-txt-link-freetext" href="http://www.martinfowler.com/eaaCatalog/singleTableInheritance.html">http://www.martinfowler.com/eaaCatalog/singleTableInheritance.html</a><br /><br/> The key, I believe, is simply adding a "type" and a "parent_id" to the "class" table, so you can model all your typesand their hierarchical relations. Fowler's diagram is pretty clear. I think then you would store the data in anothertable (or tables) and link into this inheritance structure to establish ancestry for any piece of data (some peopletry to store the data in this table too, but I think that's a mistake personally). <br /><br /> If I understand whatyou're trying to do, you can use this design pattern in your application language to implement an inheritance schemewithout any special database features (i.e. in a SQL-standard manner). <br /><br /> I hope this is helpful, <br /><br/> Steve <br /><br /><br /><br /> At 12:28 AM 3/9/2007, <a class="moz-txt-link-abbreviated" href="mailto:pgsql-sql-owner@postgresql.org">pgsql-sql-owner@postgresql.org</a>wrote: <br /><blockquote type="cite">Date:Thu, 08 Mar 2007 13:01:51 -0500 <br /> From: Greg Toombs <a class="moz-txt-link-rfc2396E" href="mailto:greg.toombs@bluebottle.com"><greg.toombs@bluebottle.com></a><br/> To: <a class="moz-txt-link-abbreviated"href="mailto:pgsql-sql@postgresql.org">pgsql-sql@postgresql.org</a><br /> Subject: A formof inheritance with PostgreSQL <br /> Message-ID: <a class="moz-txt-link-rfc2396E" href="mailto:45F04F8F.8030800@bluebottle.com"><45F04F8F.8030800@bluebottle.com></a><br/><br /> Hello. <br /><br />I'm trying to figure out how to nicely implement a C++ class-like system <br /> with PostgreSQL. Consider the following:<br /><br /> Tables Fruit, Apple, Orange <br /><br /> I want to design the foreign key scheme such that there arerelations <br /> between fruit and apple, and fruit and orange, that imply that apple is a <br /> fruit, and orange isa fruit. <br /><br /> I don't want to eliminate the existence of Apple and Orange tables, <br /> because there will becolumns specific to both Apple and Orange; if I <br /> include these columns in Fruit, then if Fruit is an Orange, theApple <br /> columns will be needlessly present in Apple rows. <br /><br /> The different ways of implementing this schemethat I've thought of (some <br /> uglier than others): <br /><br /> - Have Fruit contain foreign keys to both Appleand Orange, and write a <br /> check constraint in Fruit specifying that exactly one of (Apple FK, <br /> Orange FK)needs to be non-null. The disadvantage of this method is that <br /> it isn't exactly loosely coupled. For every otherfruit type table I <br /> implemented I'd have to go back and add a foreign key in Fruit. <br /><br /> - Have a foreignkey in Apple to Fruit, and in Orange to Fruit; then <br /> somehow create a constraint that imposes uniqueness onthe union of <br /> foreign keys in both Apple and Orange. To figure out what type of fruit a <br /> Fruit row is, runa query for foreign keys in Orange and Apple matching <br /> the primary key of Fruit. You'd also want to somehow createa constraint <br /> that the result of this query should always return exactly one row <br /> (perhaps with a trigger?)<br /><br /> Any advice will be appreciated! As I'm relatively new to Postgre, I might <br /> need some help withthe actual implementation as well. <br /><br /> Thank you. <br /><br /> - Greg <br /></blockquote><br /><br /> ---------------------------(endof broadcast)--------------------------- <br /> TIP 6: explain analyze is your friend <br/></blockquote><br />
Greg Toombs <greg.toombs@bluebottle.com> writes: > After reading a few more methods of doing things, I went with the > simplest one, as 1. time is of the essence, and 2. I'm stuck with > PostgreSQL 7.1 on the server I have to develop for.<br> Egad. *Please* do not tell us you are intending to use 7.1 for production ... if some PHB is trying to force that on you, I suggest resigning from the project before you get blamed for the inevitable disaster. regards, tom lane
What disaster do you foresee? Is that version unstable?<br /><br /> Tom Lane wrote: <blockquote cite="mid22201.1173749046@sss.pgh.pa.us"type="cite"><p>Greg Toombs <a class="moz-txt-link-rfc2396E" href="mailto:greg.toombs@bluebottle.com"><greg.toombs@bluebottle.com></a>writes:<br /><blockquote type="cite"><p>Afterreading a few more methods of doing things, I went with the<br /> simplest one, as 1. time is of theessence, and 2. I'm stuck with<br /> PostgreSQL 7.1 on the server I have to develop for.<br /></blockquote><p>Egad. *Please*do not tell us you are intending to use 7.1 for production<br /> .... if some PHB is trying to force that on you,I suggest resigning from<br /> the project before you get blamed for the inevitable disaster.<br /><br /> regards, tomlane</blockquote>
Greg Toombs wrote: > What disaster do you foresee? Is that version unstable? Yes. There are known, unfixed bugs, and architectural problems that cannot be fixed. -- Alvaro Herrera http://www.CommandPrompt.com/ The PostgreSQL Company - Command Prompt, Inc.
<p>Hoookay. I'm currently negotiating with IX Webhosting to upgrade their prehistoric software. Fellows, consider this aword of warning that, if they don't upgrade, anyone wanting to use this host will be stuck with PostgreSQL 7.1.3. If theydo upgrade, I'll happily revoke this warning. Anyway, thanks for the heads-up.<br /><p>Alvaro Herrera wrote:<blockquotecite="mid20070313032139.GS7700@alvh.no-ip.org" type="cite"><p>Greg Toombs wrote:<blockquote type="cite"><p>Whatdisaster do you foresee? Is that version unstable?</blockquote><p>Yes. There are known, unfixed bugs,and architectural problems that cannot be fixed.</blockquote>
Alvaro Herrera <alvherre@commandprompt.com> writes: > Greg Toombs wrote: >> What disaster do you foresee? Is that version unstable? > Yes. There are known, unfixed bugs, and architectural problems that > cannot be fixed. We abandoned maintenance of the 7.1 branch in 2001. 7.2 was the first version that anyone thought was good enough to maintain over the long haul (mainly because it was the first version that wouldn't crash and burn at 4G transactions), and even that was abandoned in 2005 because of its unfixable-without-initdb security bugs. I don't know of anyone who would recommend today that you undertake new development on a server version older than 8.1.x. regards, tom lane