From 06490a13ca944eeea8d5d8dfcc7c85444e16ad7a Mon Sep 17 00:00:00 2001 From: Mark Huang Date: Mon, 2 Oct 2006 15:19:35 +0000 Subject: [PATCH] - remove UNIQUE constraint on named keys from tables that support marking records as deleted (e.g. persons.email should not be unique; even (persons.email, persons.deleted) should not be unique, since the same person could conceivably register and delete their account multiple times). Instead, just add an index on these fields. - add indices to join tables - sites: add max_slivers attribute - get rid of address types, leave it to the application to decide how address types should be used - get rid of person/account addresses, just add site addresses - node_nodenetworks: order by is_primary - add slice and sliver tables - remove .* from all views per jonesy recommendation --- planetlab4.sql | 314 +++++++++++++++++++++++++++++++++++++++---------- 1 file changed, 252 insertions(+), 62 deletions(-) diff --git a/planetlab4.sql b/planetlab4.sql index 451a7ba..550c22d 100644 --- a/planetlab4.sql +++ b/planetlab4.sql @@ -9,7 +9,7 @@ -- -- Copyright (C) 2006 The Trustees of Princeton University -- --- $Id: planetlab4.sql,v 1.1 2006/09/25 14:40:16 mlhuang Exp $ +-- $Id: planetlab4.sql,v 1.2 2006/09/25 18:34:48 mlhuang Exp $ -- -------------------------------------------------------------------------------- @@ -33,7 +33,7 @@ CREATE AGGREGATE array_accum ( CREATE TABLE persons ( -- Mandatory person_id serial PRIMARY KEY, -- Account identifier - email text UNIQUE NOT NULL, -- E-mail address + email text NOT NULL, -- E-mail address first_name text NOT NULL, -- First name last_name text NOT NULL, -- Last name deleted boolean NOT NULL DEFAULT false, -- Has been deleted @@ -54,6 +54,7 @@ CREATE TABLE persons ( date_created timestamp without time zone NOT NULL DEFAULT CURRENT_TIMESTAMP, last_updated timestamp without time zone NOT NULL DEFAULT CURRENT_TIMESTAMP ); +CREATE INDEX persons_email_key ON persons (email); -------------------------------------------------------------------------------- -- Sites @@ -63,15 +64,13 @@ CREATE TABLE persons ( CREATE TABLE sites ( -- Mandatory site_id serial PRIMARY KEY, -- Site identifier - login_base text UNIQUE NOT NULL, -- Site slice prefix + login_base text NOT NULL, -- Site slice prefix name text NOT NULL, -- Site name abbreviated_name text NOT NULL, -- Site abbreviated name deleted boolean NOT NULL DEFAULT false, -- Has been deleted is_public boolean NOT NULL DEFAULT true, -- Shows up in public lists max_slices integer NOT NULL DEFAULT 0, -- Maximum number of slices - - -- XXX Sites should have an address - -- address_id REFERENCES addresses, + max_slivers integer NOT NULL DEFAULT 1000, -- Maximum number of instantiated slivers -- Optional latitude real, @@ -82,6 +81,7 @@ CREATE TABLE sites ( date_created timestamp without time zone NOT NULL DEFAULT CURRENT_TIMESTAMP, last_updated timestamp without time zone NOT NULL DEFAULT CURRENT_TIMESTAMP ); +CREATE INDEX sites_login_base_key ON sites (login_base); -- Account site membership CREATE TABLE person_site ( @@ -90,6 +90,8 @@ CREATE TABLE person_site ( is_primary boolean NOT NULL DEFAULT false, -- Is the primary site for this account PRIMARY KEY (person_id, site_id) ); +CREATE INDEX person_site_person_id_key ON person_site (person_id); +CREATE INDEX person_site_site_id_key ON person_site (site_id); -- Ordered by primary site first CREATE VIEW person_site_ordered AS @@ -115,18 +117,10 @@ GROUP BY site_id; -- Mailing Addresses -------------------------------------------------------------------------------- --- Valid mailing address types -CREATE TABLE address_types ( - address_type_id serial PRIMARY KEY, -- Address type identifier - address_type text UNIQUE NOT NULL -- Address type -); -INSERT INTO address_types (address_type) VALUES ('Personal'); -INSERT INTO address_types (address_type) VALUES ('Shipping'); -INSERT INTO address_types (address_type) VALUES ('Site'); - -- Mailing addresses CREATE TABLE addresses ( address_id serial PRIMARY KEY, -- Address identifier + address_type text, -- Address type, e.g. shipping or billing line1 text NOT NULL, -- Address line 1 line2 text, -- Address line 2 line3 text, -- Address line 3 @@ -136,34 +130,20 @@ CREATE TABLE addresses ( country text NOT NULL -- Country ); --- Each address can be multiple types -CREATE TABLE address_address_type ( - address_id integer REFERENCES addresses, - address_type_id integer REFERENCES address_types, - PRIMARY KEY (address_id, address_type_id) -); - --- Types of each address -CREATE VIEW address_address_types AS -SELECT address_id, -array_to_string(array_accum(address_type_id), ',') AS address_type_ids, -array_to_string(array_accum(address_type), ',') AS address_types -FROM address_address_type -LEFT JOIN address_types USING (address_type_id) -GROUP BY address_id; - -CREATE TABLE person_address ( - person_id integer REFERENCES persons, -- Account identifier +-- Site mailing addresses +CREATE TABLE site_address ( + site_id integer REFERENCES sites, -- Account identifier address_id integer REFERENCES addresses, -- Address identifier - PRIMARY KEY (person_id, address_id) + PRIMARY KEY (site_id, address_id) ); +CREATE INDEX site_address_site_id_key ON site_address (site_id); +CREATE INDEX site_address_address_id_key ON site_address (address_id); --- Account mailing addresses -CREATE VIEW person_addresses AS -SELECT person_id, +CREATE VIEW site_addresses AS +SELECT site_id, array_to_string(array_accum(address_id), ',') AS address_ids -FROM person_address -GROUP BY person_id; +FROM site_address +GROUP BY site_id; -------------------------------------------------------------------------------- -- Authentication Keys @@ -190,6 +170,8 @@ CREATE TABLE person_key ( is_primary boolean NOT NULL DEFAULT false, -- Is the primary key for this account PRIMARY KEY (person_id, key_id) ); +CREATE INDEX person_key_person_id_key ON person_key (person_id); +CREATE INDEX person_key_key_id_key ON person_key (key_id); CREATE VIEW person_keys AS SELECT person_id, @@ -218,6 +200,7 @@ CREATE TABLE person_role ( role_id integer REFERENCES roles, -- Role identifier PRIMARY KEY (person_id, role_id) ); +CREATE INDEX person_role_person_id_key ON person_role (person_id); -- Account roles CREATE VIEW person_roles AS @@ -247,7 +230,7 @@ INSERT INTO boot_states (boot_state) VALUES ('new'); CREATE TABLE nodes ( -- Mandatory node_id serial PRIMARY KEY, -- Node identifier - hostname text UNIQUE NOT NULL, -- Node hostname + hostname text NOT NULL, -- Node hostname site_id integer REFERENCES sites, -- At which site boot_state text REFERENCES boot_states, -- Node boot state deleted boolean NOT NULL DEFAULT false, -- Is deleted @@ -265,6 +248,8 @@ CREATE TABLE nodes ( date_created timestamp without time zone NOT NULL DEFAULT CURRENT_TIMESTAMP, last_updated timestamp without time zone NOT NULL DEFAULT CURRENT_TIMESTAMP ); +CREATE INDEX nodes_hostname_key ON nodes (hostname); +CREATE INDEX nodes_site_id_key ON nodes (site_id); -- Nodes at each site CREATE VIEW site_nodes AS @@ -290,6 +275,8 @@ CREATE TABLE nodegroup_node ( node_id integer REFERENCES nodes, -- Node identifier PRIMARY KEY (nodegroup_id, node_id) ); +CREATE INDEX nodegroup_node_nodegroup_id_key ON nodegroup_node (nodegroup_id); +CREATE INDEX nodegroup_node_node_id_key ON nodegroup_node (node_id); -- Nodes in each node gruop CREATE VIEW nodegroup_nodes AS @@ -348,59 +335,262 @@ CREATE TABLE nodenetworks ( bwlimit integer, -- Bandwidth limit in bps hostname text -- Hostname of this interface ); +CREATE INDEX nodenetworks_node_id_key ON nodenetworks (node_id); + +-- Ordered by primary interface first +CREATE VIEW nodenetworks_ordered AS +SELECT node_id, nodenetwork_id +FROM nodenetworks +ORDER BY is_primary DESC; -- Network interfaces on each node CREATE VIEW node_nodenetworks AS SELECT node_id, array_to_string(array_accum(nodenetwork_id), ',') AS nodenetwork_ids -FROM nodenetworks +FROM nodenetworks_ordered +GROUP BY node_id; + +-------------------------------------------------------------------------------- +-- Slices +-------------------------------------------------------------------------------- + +CREATE TABLE slice_instantiations ( + instantiation text PRIMARY KEY +); +INSERT INTO slice_instantiations (instantiation) VALUES ('not-instantiated'); -- Placeholder slice +INSERT INTO slice_instantiations (instantiation) VALUES ('plc-instantiated'); -- Instantiated by Node Manager +INSERT INTO slice_instantiations (instantiation) VALUES ('delegated'); -- Manually instantiated + +-- Slices +CREATE TABLE slices ( + slice_id serial PRIMARY KEY, -- Slice identifier + site_id integer REFERENCES sites, -- Site identifier + name text NOT NULL, -- Slice name + instantiation text REFERENCES slice_instantiations DEFAULT 'plc-instantiated', -- Slice state, e.g. plc-instantiated + url text, -- Project URL + description text, -- Project description + + max_nodes integer NOT NULL DEFAULT 100, -- Maximum number of nodes that can be assigned to this slice + + creator_person_id integer REFERENCES persons, -- Creator + created timestamp without time zone NOT NULL DEFAULT CURRENT_TIMESTAMP, -- Creation date + expires timestamp without time zone NOT NULL DEFAULT CURRENT_TIMESTAMP + '2 weeks', -- Expiration date + + is_deleted boolean NOT NULL DEFAULT false +); +CREATE INDEX slices_site_id_key ON slices (site_id); +CREATE INDEX slices_name_key ON slices (name); + +-- Slivers +CREATE TABLE slice_node ( + slice_id integer REFERENCES slices, -- Slice identifier + node_id integer REFERENCES nodes -- Node identifier +); +CREATE INDEX slice_node_slice_id_key ON slice_node (slice_id); +CREATE INDEX slice_node_node_id_key ON slice_node (node_id); + +-- Synonym for slice_node +CREATE VIEW slivers AS +SELECT * FROM slice_node; + +-- Nodes in each slice +CREATE VIEW slice_nodes AS +SELECT slice_id, +array_to_string(array_accum(node_id), ',') AS node_ids +FROM slice_node +GROUP BY slice_id; + +-- Slices on each node +CREATE VIEW node_slices AS +SELECT node_id, +array_to_string(array_accum(slice_id), ',') AS slice_ids +FROM slice_node GROUP BY node_id; +-- Slices at each site +CREATE VIEW site_slices AS +SELECT site_id, +array_to_string(array_accum(slice_id), ',') AS slice_ids +FROM slices +GROUP BY site_id; + +-- Slice membership +CREATE TABLE slice_person ( + slice_id integer REFERENCES slices, -- Slice identifier + person_id integer REFERENCES persons, -- Account identifier + PRIMARY KEY (slice_id, person_id) +); +CREATE INDEX slice_person_slice_id_key ON slice_person (slice_id); +CREATE INDEX slice_person_person_id_key ON slice_person (person_id); + +-- Members of the slice +CREATE VIEW slice_persons AS +SELECT slice_id, +array_to_string(array_accum(person_id), ',') AS person_ids +FROM slice_person +GROUP BY slice_id; + +-- Slices of which each person is a member +CREATE VIEW person_slices AS +SELECT person_id, +array_to_string(array_accum(slice_id), ',') AS slice_ids +FROM slice_person +GROUP BY person_id; + +-------------------------------------------------------------------------------- +-- Slice attributes +-------------------------------------------------------------------------------- + +CREATE TABLE attributes ( + attribute_id serial PRIMARY KEY, -- Attribute identifier + name text UNIQUE NOT NULL, -- Attribute name + description text, -- Attribute description + min_role_id integer REFERENCES roles -- Minimum (least powerful) role that can set or change this attribute +); + +-- Slice/sliver attributes +CREATE TABLE slice_attribute ( + slice_id integer REFERENCES slices, -- Slice identifier + attribute_id integer REFERENCES attributes, -- Attribute identifier + node_id integer, -- Sliver attribute if set + value text, + PRIMARY KEY (slice_id, attribute_id, node_id) +); +CREATE INDEX slice_attribute_slice_id_key ON slice_attribute (slice_id); +CREATE INDEX slice_attribute_node_id_key ON slice_attribute (node_id); + +CREATE VIEW slice_attributes AS +SELECT slice_id, +array_to_string(array_accum(attribute_id), ',') AS attribute_ids +FROM slice_attribute +WHERE node_id IS NULL +GROUP BY slice_id; + +-- No sliver_attributes view since it by definition requires a conditional on node_id + -------------------------------------------------------------------------------- -- Useful views -------------------------------------------------------------------------------- CREATE VIEW view_persons AS -SELECT persons.*, -person_roles.role_ids, -person_roles.roles, +SELECT +persons.person_id, +persons.email, +persons.first_name, +persons.last_name, +persons.deleted, +persons.enabled, +persons.password, +persons.verification_key, +persons.verification_expires, +persons.title, +persons.phone, +persons.url, +persons.bio, +CAST(date_part('epoch', persons.date_created) AS bigint) AS date_created, +CAST(date_part('epoch', persons.last_updated) AS bigint) AS last_updated, +person_roles.role_ids, person_roles.roles, person_sites.site_ids, -person_addresses.address_ids, -person_keys.key_ids +person_keys.key_ids, +person_slices.slice_ids FROM persons LEFT JOIN person_roles USING (person_id) LEFT JOIN person_sites USING (person_id) -LEFT JOIN person_addresses USING (person_id) -LEFT JOIN person_keys USING (person_id); - -CREATE VIEW view_addresses AS -SELECT addresses.*, -address_address_types.address_type_ids, -address_address_types.address_types -FROM addresses -LEFT JOIN address_address_types USING (address_id); +LEFT JOIN person_keys USING (person_id) +LEFT JOIN person_slices USING (person_id); CREATE VIEW view_nodes AS -SELECT nodes.*, +SELECT +nodes.node_id, +nodes.hostname, +nodes.site_id, +nodes.boot_state, +nodes.deleted, +nodes.model, +nodes.boot_nonce, +nodes.version, +nodes.ssh_rsa_key, +nodes.key, +nodes.session, +CAST(date_part('epoch', nodes.date_created) AS bigint) AS date_created, +CAST(date_part('epoch', nodes.last_updated) AS bigint) AS last_updated, node_nodenetworks.nodenetwork_ids, -node_nodegroups.nodegroup_ids +node_nodegroups.nodegroup_ids, +node_slices.slice_ids FROM nodes LEFT JOIN node_nodenetworks USING (node_id) -LEFT JOIN node_nodegroups USING (node_id); +LEFT JOIN node_nodegroups USING (node_id) +LEFT JOIN node_slices USING (node_id); CREATE VIEW view_nodegroups AS -SELECT nodegroups.*, +SELECT +nodegroups.nodegroup_id, +nodegroups.name, +nodegroups.description, nodegroup_nodes.node_ids FROM nodegroups LEFT JOIN nodegroup_nodes USING (nodegroup_id); CREATE VIEW view_sites AS -SELECT sites.*, +SELECT +sites.site_id, +sites.login_base, +sites.name, +sites.abbreviated_name, +sites.deleted, +sites.is_public, +sites.max_slices, +sites.max_slivers, +sites.latitude, +sites.longitude, +sites.url, +CAST(date_part('epoch', sites.date_created) AS bigint) AS date_created, +CAST(date_part('epoch', sites.last_updated) AS bigint) AS last_updated, site_persons.person_ids, -site_nodes.node_ids +site_nodes.node_ids, +site_addresses.address_ids, +site_slices.slice_ids FROM sites LEFT JOIN site_persons USING (site_id) -LEFT JOIN site_nodes USING (site_id); +LEFT JOIN site_nodes USING (site_id) +LEFT JOIN site_addresses USING (site_id) +LEFT JOIN site_slices USING (site_id); + +CREATE VIEW view_addresses AS +SELECT +addresses.address_id, +addresses.address_type, +addresses.line1, +addresses.line2, +addresses.line3, +addresses.city, +addresses.state, +addresses.postalcode, +addresses.country, +site_address.site_id +FROM addresses +LEFT JOIN site_address USING (address_id); + +CREATE VIEW view_slices AS +SELECT +slices.slice_id, +slices.site_id, +slices.name, +slices.instantiation, +slices.url, +slices.description, +slices.max_nodes, +slices.creator_person_id, +slices.is_deleted, +CAST(date_part('epoch', slices.created) AS bigint) AS created, +CAST(date_part('epoch', slices.expires) AS bigint) AS expires, +slice_nodes.node_ids, +slice_persons.person_ids, +slice_attributes.attribute_ids +FROM slices +LEFT JOIN slice_nodes USING (slice_id) +LEFT JOIN slice_persons USING (slice_id) +LEFT JOIN slice_attributes USING (slice_id); -------------------------------------------------------------------------------- -- Built-in maintenance account and default site -- 2.43.0