2 -- PlanetLab Central database schema
3 -- Version 4, PostgreSQL
5 -- Aaron Klingaman <alk@cs.princeton.edu>
6 -- Reid Moran <rmoran@cs.princeton.edu>
7 -- Mark Huang <mlhuang@cs.princeton.edu>
8 -- Tony Mack <tmack@cs.princeton.edu>
10 -- Copyright (C) 2006 The Trustees of Princeton University
12 -- $Id: planetlab4.sql,v 1.46 2006/11/27 12:18:12 thierry Exp $
15 --------------------------------------------------------------------------------
16 -- Aggregates and store procedures
17 --------------------------------------------------------------------------------
19 -- Like MySQL GROUP_CONCAT(), this function aggregates values into a
21 CREATE AGGREGATE array_accum (
23 basetype = anyelement,
28 --------------------------------------------------------------------------------
30 --------------------------------------------------------------------------------
33 CREATE TABLE plc_db_version (
34 version integer NOT NULL
37 INSERT INTO plc_db_version (version) VALUES (4);
39 --------------------------------------------------------------------------------
41 --------------------------------------------------------------------------------
45 peer_id serial PRIMARY KEY, -- identifier
46 peername text NOT NULL, -- free text
47 peer_url text NOT NULL, -- the url of that peer's API
48 -- oops, looks like we have a dependency loop here
49 --person_id integer REFERENCES persons NOT NULL, -- the account we use for logging in
50 person_id integer NOT NULL, -- the account we use for logging in
52 deleted boolean NOT NULL DEFAULT false
55 --------------------------------------------------------------------------------
57 --------------------------------------------------------------------------------
60 CREATE TABLE persons (
62 person_id serial PRIMARY KEY, -- Account identifier
63 email text NOT NULL, -- E-mail address
64 first_name text NOT NULL, -- First name
65 last_name text NOT NULL, -- Last name
66 deleted boolean NOT NULL DEFAULT false, -- Has been deleted
67 enabled boolean NOT NULL DEFAULT false, -- Has been disabled
70 password text NOT NULL, -- Password (md5crypted)
71 verification_key text, -- Reset password key
72 verification_expires timestamp without time zone,
75 title text, -- Honorific
76 phone text, -- Telephone number
77 url text, -- Home page
78 bio text, -- Biography
81 date_created timestamp without time zone NOT NULL DEFAULT CURRENT_TIMESTAMP,
82 last_updated timestamp without time zone NOT NULL DEFAULT CURRENT_TIMESTAMP,
84 peer_id integer REFERENCES peers -- From which peer
86 CREATE INDEX persons_email_idx ON persons (email) WHERE deleted IS false;
88 --------------------------------------------------------------------------------
90 --------------------------------------------------------------------------------
95 site_id serial PRIMARY KEY, -- Site identifier
96 login_base text NOT NULL, -- Site slice prefix
97 name text NOT NULL, -- Site name
98 abbreviated_name text NOT NULL, -- Site abbreviated name
99 deleted boolean NOT NULL DEFAULT false, -- Has been deleted
100 is_public boolean NOT NULL DEFAULT true, -- Shows up in public lists
101 max_slices integer NOT NULL DEFAULT 0, -- Maximum number of slices
102 max_slivers integer NOT NULL DEFAULT 1000, -- Maximum number of instantiated slivers
110 date_created timestamp without time zone NOT NULL DEFAULT CURRENT_TIMESTAMP,
111 last_updated timestamp without time zone NOT NULL DEFAULT CURRENT_TIMESTAMP,
113 peer_id integer REFERENCES peers -- From which peer
115 CREATE INDEX sites_login_base_idx ON sites (login_base) WHERE deleted IS false;
117 -- Account site membership
118 CREATE TABLE person_site (
119 person_id integer REFERENCES persons NOT NULL, -- Account identifier
120 site_id integer REFERENCES sites NOT NULL, -- Site identifier
121 is_primary boolean NOT NULL DEFAULT false, -- Is the primary site for this account
122 PRIMARY KEY (person_id, site_id)
124 CREATE INDEX person_site_person_id_idx ON person_site (person_id);
125 CREATE INDEX person_site_site_id_idx ON person_site (site_id);
127 -- Ordered by primary site first
128 CREATE VIEW person_site_ordered AS
129 SELECT person_id, site_id
131 ORDER BY is_primary DESC;
133 -- Sites that each person is a member of
134 CREATE VIEW person_sites AS
136 array_accum(site_id) AS site_ids
137 FROM person_site_ordered
140 -- Accounts at each site
141 CREATE VIEW site_persons AS
143 array_accum(person_id) AS person_ids
147 --------------------------------------------------------------------------------
149 --------------------------------------------------------------------------------
151 CREATE TABLE address_types (
152 address_type_id serial PRIMARY KEY, -- Address type identifier
153 name text UNIQUE NOT NULL, -- Address type
154 description text -- Address type description
157 INSERT INTO address_types (name) VALUES ('Personal');
158 INSERT INTO address_types (name) VALUES ('Shipping');
159 -- XXX Used to be Site
160 INSERT INTO address_types (name) VALUES ('Billing');
163 CREATE TABLE addresses (
164 address_id serial PRIMARY KEY, -- Address identifier
165 line1 text NOT NULL, -- Address line 1
166 line2 text, -- Address line 2
167 line3 text, -- Address line 3
168 city text NOT NULL, -- City
169 state text NOT NULL, -- State or province
170 postalcode text NOT NULL, -- Postal code
171 country text NOT NULL -- Country
174 -- Each mailing address can be one of several types
175 CREATE TABLE address_address_type (
176 address_id integer REFERENCES addresses NOT NULL, -- Address identifier
177 address_type_id integer REFERENCES address_types NOT NULL, -- Address type
178 PRIMARY KEY (address_id, address_type_id)
180 CREATE INDEX address_address_type_address_id_idx ON address_address_type (address_id);
181 CREATE INDEX address_address_type_address_type_id_idx ON address_address_type (address_type_id);
183 CREATE VIEW address_address_types AS
185 array_accum(address_type_id) AS address_type_ids,
186 array_accum(address_types.name) AS address_types
187 FROM address_address_type
188 LEFT JOIN address_types USING (address_type_id)
191 CREATE TABLE site_address (
192 site_id integer REFERENCES sites NOT NULL, -- Site identifier
193 address_id integer REFERENCES addresses NOT NULL, -- Address identifier
194 PRIMARY KEY (site_id, address_id)
196 CREATE INDEX site_address_site_id_idx ON site_address (site_id);
197 CREATE INDEX site_address_address_id_idx ON site_address (address_id);
199 CREATE VIEW site_addresses AS
201 array_accum(address_id) AS address_ids
205 --------------------------------------------------------------------------------
206 -- Authentication Keys
207 --------------------------------------------------------------------------------
210 CREATE TABLE key_types (
211 key_type text PRIMARY KEY -- Key type
213 INSERT INTO key_types (key_type) VALUES ('ssh');
215 -- Authentication keys
217 key_id serial PRIMARY KEY, -- Key identifier
218 key_type text REFERENCES key_types NOT NULL, -- Key type
219 key text NOT NULL, -- Key material
220 is_blacklisted boolean NOT NULL DEFAULT false, -- Has been blacklisted
221 peer_id integer REFERENCES peers -- From which peer
224 -- Account authentication key(s)
225 CREATE TABLE person_key (
226 person_id integer REFERENCES persons NOT NULL, -- Account identifier
227 key_id integer REFERENCES keys NOT NULL, -- Key identifier
228 PRIMARY KEY (person_id, key_id)
230 CREATE INDEX person_key_person_id_idx ON person_key (person_id);
231 CREATE INDEX person_key_key_id_idx ON person_key (key_id);
233 CREATE VIEW person_keys AS
235 array_accum(key_id) AS key_ids
239 --------------------------------------------------------------------------------
241 --------------------------------------------------------------------------------
243 -- Valid account roles
245 role_id integer PRIMARY KEY, -- Role identifier
246 name text UNIQUE NOT NULL -- Role symbolic name
248 INSERT INTO roles (role_id, name) VALUES (10, 'admin');
249 INSERT INTO roles (role_id, name) VALUES (20, 'pi');
250 INSERT INTO roles (role_id, name) VALUES (30, 'user');
251 INSERT INTO roles (role_id, name) VALUES (40, 'tech');
252 INSERT INTO roles (role_id, name) VALUES (1000, 'node');
253 INSERT INTO roles (role_id, name) VALUES (2000, 'anonymous');
254 -- xxx not sure this us useful yet
255 --INSERT INTO roles (role_id, name) VALUES (3000, 'peer');
257 CREATE TABLE person_role (
258 person_id integer REFERENCES persons NOT NULL, -- Account identifier
259 role_id integer REFERENCES roles NOT NULL, -- Role identifier
260 PRIMARY KEY (person_id, role_id)
262 CREATE INDEX person_role_person_id_idx ON person_role (person_id);
265 CREATE VIEW person_roles AS
267 array_accum(role_id) AS role_ids,
268 array_accum(roles.name) AS roles
270 LEFT JOIN roles USING (role_id)
273 --------------------------------------------------------------------------------
275 --------------------------------------------------------------------------------
277 -- Valid node boot states
278 CREATE TABLE boot_states (
279 boot_state text PRIMARY KEY
281 INSERT INTO boot_states (boot_state) VALUES ('boot');
282 INSERT INTO boot_states (boot_state) VALUES ('dbg');
283 INSERT INTO boot_states (boot_state) VALUES ('inst');
284 INSERT INTO boot_states (boot_state) VALUES ('rins');
285 INSERT INTO boot_states (boot_state) VALUES ('rcnf');
286 INSERT INTO boot_states (boot_state) VALUES ('new');
291 node_id serial PRIMARY KEY, -- Node identifier
292 hostname text NOT NULL, -- Node hostname
293 -- temporarily removed NOT NULL clause for foreign_nodes
294 site_id integer REFERENCES sites, -- At which site
295 -- may be NULL for local_nodes
296 peer_id integer REFERENCES peers, -- From which peer
298 boot_state text REFERENCES boot_states NOT NULL DEFAULT 'inst', -- Node boot state
299 deleted boolean NOT NULL DEFAULT false, -- Is deleted
302 model text, -- Hardware make and model
303 boot_nonce text, -- Random nonce updated by Boot Manager
304 version text, -- Boot CD version string updated by Boot Manager
305 -- XXX Should be key_id integer REFERENCES keys
306 ssh_rsa_key text, -- SSH host key updated by Boot Manager
307 key text, -- Node key generated by API when configuration file is downloaded
310 date_created timestamp without time zone NOT NULL DEFAULT CURRENT_TIMESTAMP,
311 last_updated timestamp without time zone NOT NULL DEFAULT CURRENT_TIMESTAMP
313 CREATE INDEX nodes_hostname_idx ON nodes (hostname) WHERE deleted IS false;
314 CREATE INDEX nodes_site_id_idx ON nodes (site_id) WHERE deleted IS false;
316 -- Nodes at each site
317 CREATE VIEW site_nodes AS
319 array_accum(node_id) AS node_ids
323 -- Nodes at each peer
324 CREATE VIEW peer_nodes AS
326 array_accum(node_id) AS node_ids
330 --------------------------------------------------------------------------------
332 --------------------------------------------------------------------------------
335 CREATE TABLE nodegroups (
336 nodegroup_id serial PRIMARY KEY, -- Group identifier
337 name text UNIQUE NOT NULL, -- Group name
338 description text -- Group description
341 -- Node group membership
342 CREATE TABLE nodegroup_node (
343 nodegroup_id integer REFERENCES nodegroups NOT NULL, -- Group identifier
344 node_id integer REFERENCES nodes NOT NULL, -- Node identifier
345 PRIMARY KEY (nodegroup_id, node_id)
347 CREATE INDEX nodegroup_node_nodegroup_id_idx ON nodegroup_node (nodegroup_id);
348 CREATE INDEX nodegroup_node_node_id_idx ON nodegroup_node (node_id);
350 -- Nodes in each node group
351 CREATE VIEW nodegroup_nodes AS
353 array_accum(node_id) AS node_ids
355 GROUP BY nodegroup_id;
357 -- Node groups that each node is a member of
358 CREATE VIEW node_nodegroups AS
360 array_accum(nodegroup_id) AS nodegroup_ids
364 --------------------------------------------------------------------------------
365 -- Node configuration files
366 --------------------------------------------------------------------------------
368 CREATE TABLE conf_files (
369 conf_file_id serial PRIMARY KEY, -- Configuration file identifier
370 enabled bool NOT NULL DEFAULT true, -- Configuration file is active
371 source text NOT NULL, -- Relative path on the boot server where file can be downloaded
372 dest text NOT NULL, -- Absolute path where file should be installed
373 file_permissions text NOT NULL DEFAULT '0644', -- chmod(1) permissions
374 file_owner text NOT NULL DEFAULT 'root', -- chown(1) owner
375 file_group text NOT NULL DEFAULT 'root', -- chgrp(1) owner
376 preinstall_cmd text, -- Shell command to execute prior to installing
377 postinstall_cmd text, -- Shell command to execute after installing
378 error_cmd text, -- Shell command to execute if any error occurs
379 ignore_cmd_errors bool NOT NULL DEFAULT false, -- Install file anyway even if an error occurs
380 always_update bool NOT NULL DEFAULT false -- Always attempt to install file even if unchanged
383 CREATE TABLE conf_file_node (
384 conf_file_id integer REFERENCES conf_files NOT NULL, -- Configuration file identifier
385 node_id integer REFERENCES nodes NOT NULL, -- Node identifier
386 PRIMARY KEY (conf_file_id, node_id)
388 CREATE INDEX conf_file_node_conf_file_id_idx ON conf_file_node (conf_file_id);
389 CREATE INDEX conf_file_node_node_id_idx ON conf_file_node (node_id);
391 -- Nodes linked to each configuration file
392 CREATE VIEW conf_file_nodes AS
394 array_accum(node_id) AS node_ids
396 GROUP BY conf_file_id;
398 -- Configuration files linked to each node
399 CREATE VIEW node_conf_files AS
401 array_accum(conf_file_id) AS conf_file_ids
405 CREATE TABLE conf_file_nodegroup (
406 conf_file_id integer REFERENCES conf_files NOT NULL, -- Configuration file identifier
407 nodegroup_id integer REFERENCES nodegroups NOT NULL, -- Node group identifier
408 PRIMARY KEY (conf_file_id, nodegroup_id)
410 CREATE INDEX conf_file_nodegroup_conf_file_id_idx ON conf_file_nodegroup (conf_file_id);
411 CREATE INDEX conf_file_nodegroup_nodegroup_id_idx ON conf_file_nodegroup (nodegroup_id);
413 -- Node groups linked to each configuration file
414 CREATE VIEW conf_file_nodegroups AS
416 array_accum(nodegroup_id) AS nodegroup_ids
417 FROM conf_file_nodegroup
418 GROUP BY conf_file_id;
420 -- Configuration files linked to each node group
421 CREATE VIEW nodegroup_conf_files AS
423 array_accum(conf_file_id) AS conf_file_ids
424 FROM conf_file_nodegroup
425 GROUP BY nodegroup_id;
427 --------------------------------------------------------------------------------
428 -- Node network interfaces
429 --------------------------------------------------------------------------------
431 -- Valid network addressing schemes
432 CREATE TABLE network_types (
433 type text PRIMARY KEY -- Addressing scheme
435 INSERT INTO network_types (type) VALUES ('ipv4');
437 -- Valid network configuration methods
438 CREATE TABLE network_methods (
439 method text PRIMARY KEY -- Configuration method
441 INSERT INTO network_methods (method) VALUES ('static');
442 INSERT INTO network_methods (method) VALUES ('dhcp');
443 INSERT INTO network_methods (method) VALUES ('proxy');
444 INSERT INTO network_methods (method) VALUES ('tap');
445 INSERT INTO network_methods (method) VALUES ('ipmi');
446 INSERT INTO network_methods (method) VALUES ('unknown');
448 -- Node network interfaces
449 CREATE TABLE nodenetworks (
451 nodenetwork_id serial PRIMARY KEY, -- Network interface identifier
452 node_id integer REFERENCES nodes NOT NULL, -- Which node
453 is_primary boolean NOT NULL DEFAULT false, -- Is the primary interface for this node
454 type text REFERENCES network_types NOT NULL, -- Addressing scheme
455 method text REFERENCES network_methods NOT NULL, -- Configuration method
457 -- Optional, depending on type and method
458 ip text, -- IP address
459 mac text, -- MAC address
460 gateway text, -- Default gateway address
461 network text, -- Network address
462 broadcast text, -- Network broadcast address
463 netmask text, -- Network mask
464 dns1 text, -- Primary DNS server
465 dns2 text, -- Secondary DNS server
466 bwlimit integer, -- Bandwidth limit in bps
467 hostname text -- Hostname of this interface
469 CREATE INDEX nodenetworks_node_id_idx ON nodenetworks (node_id);
471 -- Ordered by primary interface first
472 CREATE VIEW nodenetworks_ordered AS
473 SELECT node_id, nodenetwork_id
475 ORDER BY is_primary DESC;
477 -- Network interfaces on each node
478 CREATE VIEW node_nodenetworks AS
480 array_accum(nodenetwork_id) AS nodenetwork_ids
481 FROM nodenetworks_ordered
484 --------------------------------------------------------------------------------
485 -- Power control units (PCUs)
486 --------------------------------------------------------------------------------
490 pcu_id serial PRIMARY KEY, -- PCU identifier
491 site_id integer REFERENCES sites NOT NULL, -- Site identifier
492 hostname text, -- Hostname, not necessarily unique (multiple logical sites could use the same PCU)
493 ip text NOT NULL, -- IP, not necessarily unique
496 protocol text, -- Protocol, e.g. ssh or https or telnet
497 username text, -- Username, if applicable
498 "password" text, -- Password, if applicable
499 model text, -- Model, e.g. BayTech or iPal
500 notes text -- Random notes
502 CREATE INDEX pcus_site_id_idx ON pcus (site_id);
504 CREATE VIEW site_pcus AS
506 array_accum(pcu_id) AS pcu_ids
510 CREATE TABLE pcu_node (
511 pcu_id integer REFERENCES pcus NOT NULL, -- PCU identifier
512 node_id integer REFERENCES nodes NOT NULL, -- Node identifier
513 port integer NOT NULL, -- Port number
514 PRIMARY KEY (pcu_id, node_id), -- The same node cannot be controlled by different ports
515 UNIQUE (pcu_id, port) -- The same port cannot control multiple nodes
517 CREATE INDEX pcu_node_pcu_id_idx ON pcu_node (pcu_id);
518 CREATE INDEX pcu_node_node_id_idx ON pcu_node (node_id);
520 CREATE VIEW node_pcus AS
522 array_accum(pcu_id) AS pcu_ids,
523 array_accum(port) AS ports
527 CREATE VIEW pcu_nodes AS
529 array_accum(node_id) AS node_ids,
530 array_accum(port) AS ports
534 --------------------------------------------------------------------------------
536 --------------------------------------------------------------------------------
538 CREATE TABLE slice_instantiations (
539 instantiation text PRIMARY KEY
541 INSERT INTO slice_instantiations (instantiation) VALUES ('not-instantiated'); -- Placeholder slice
542 INSERT INTO slice_instantiations (instantiation) VALUES ('plc-instantiated'); -- Instantiated by Node Manager
543 INSERT INTO slice_instantiations (instantiation) VALUES ('delegated'); -- Manually instantiated
546 CREATE TABLE slices (
547 slice_id serial PRIMARY KEY, -- Slice identifier
548 -- xxx temporarily remove the NOT NULL constraint
549 site_id integer REFERENCES sites, -- Site identifier
550 peer_id integer REFERENCES peers, -- on which peer
552 name text NOT NULL, -- Slice name
553 instantiation text REFERENCES slice_instantiations NOT NULL DEFAULT 'plc-instantiated', -- Slice state, e.g. plc-instantiated
554 url text, -- Project URL
555 description text, -- Project description
557 max_nodes integer NOT NULL DEFAULT 100, -- Maximum number of nodes that can be assigned to this slice
559 -- xxx temporarily remove the NOT NULL constraint
560 creator_person_id integer REFERENCES persons, -- Creator
561 created timestamp without time zone NOT NULL DEFAULT CURRENT_TIMESTAMP, -- Creation date
562 expires timestamp without time zone NOT NULL DEFAULT CURRENT_TIMESTAMP + '2 weeks', -- Expiration date
564 is_deleted boolean NOT NULL DEFAULT false
566 CREATE INDEX slices_site_id_idx ON slices (site_id) WHERE is_deleted IS false;
567 CREATE INDEX slices_name_idx ON slices (name) WHERE is_deleted IS false;
570 CREATE TABLE slice_node (
571 slice_id integer REFERENCES slices NOT NULL, -- Slice identifier
572 node_id integer REFERENCES nodes NOT NULL, -- Node identifier
573 PRIMARY KEY (slice_id, node_id)
575 CREATE INDEX slice_node_slice_id_idx ON slice_node (slice_id);
576 CREATE INDEX slice_node_node_id_idx ON slice_node (node_id);
578 -- Synonym for slice_node
579 CREATE VIEW slivers AS
580 SELECT * FROM slice_node;
582 -- Nodes in each slice
583 CREATE VIEW slice_nodes AS
585 array_accum(node_id) AS node_ids
589 -- Slices on each node
590 CREATE VIEW node_slices AS
592 array_accum(slice_id) AS slice_ids
596 -- Slices at each site
597 CREATE VIEW site_slices AS
599 array_accum(slice_id) AS slice_ids
601 WHERE is_deleted is false
604 CREATE VIEW peer_slices AS
606 array_accum(slice_id) AS slice_ids
611 CREATE TABLE slice_person (
612 slice_id integer REFERENCES slices NOT NULL, -- Slice identifier
613 person_id integer REFERENCES persons NOT NULL, -- Account identifier
614 PRIMARY KEY (slice_id, person_id)
616 CREATE INDEX slice_person_slice_id_idx ON slice_person (slice_id);
617 CREATE INDEX slice_person_person_id_idx ON slice_person (person_id);
619 -- Members of the slice
620 CREATE VIEW slice_persons AS
622 array_accum(person_id) AS person_ids
626 -- Slices of which each person is a member
627 CREATE VIEW person_slices AS
629 array_accum(slice_id) AS slice_ids
633 --------------------------------------------------------------------------------
635 --------------------------------------------------------------------------------
637 -- Slice attribute types
638 CREATE TABLE slice_attribute_types (
639 attribute_type_id serial PRIMARY KEY, -- Attribute type identifier
640 name text UNIQUE NOT NULL, -- Attribute name
641 description text, -- Attribute description
642 min_role_id integer REFERENCES roles DEFAULT 10, -- If set, minimum (least powerful) role that can set or change this attribute
644 peer_id integer REFERENCES peers -- From which peer
647 -- Slice/sliver attributes
648 CREATE TABLE slice_attribute (
649 slice_attribute_id serial PRIMARY KEY, -- Slice attribute identifier
650 slice_id integer REFERENCES slices NOT NULL, -- Slice identifier
651 node_id integer REFERENCES nodes, -- Sliver attribute if set
652 attribute_type_id integer REFERENCES slice_attribute_types NOT NULL, -- Attribute type identifier
655 peer_id integer REFERENCES peers -- From which peer
657 CREATE INDEX slice_attribute_slice_id_idx ON slice_attribute (slice_id);
658 CREATE INDEX slice_attribute_node_id_idx ON slice_attribute (node_id);
660 CREATE VIEW slice_attributes AS
662 array_accum(slice_attribute_id) AS slice_attribute_ids
666 --------------------------------------------------------------------------------
667 -- Authenticated sessions
668 --------------------------------------------------------------------------------
670 -- Authenticated sessions
671 CREATE TABLE sessions (
672 session_id text PRIMARY KEY, -- Session identifier
673 expires timestamp without time zone
676 -- People can have multiple sessions
677 CREATE TABLE person_session (
678 person_id integer REFERENCES persons NOT NULL, -- Account identifier
679 session_id text REFERENCES sessions NOT NULL, -- Session identifier
680 PRIMARY KEY (person_id, session_id),
681 UNIQUE (session_id) -- Sessions are unique
683 CREATE INDEX person_session_person_id_idx ON person_session (person_id);
685 -- Nodes can have only one session
686 CREATE TABLE node_session (
687 node_id integer REFERENCES nodes NOT NULL, -- Node identifier
688 session_id text REFERENCES sessions NOT NULL, -- Session identifier
689 UNIQUE (node_id), -- Nodes can have only one session
690 UNIQUE (session_id) -- Sessions are unique
693 --------------------------------------------------------------------------------
695 --------------------------------------------------------------------------------
697 CREATE TABLE messages (
698 message_id text PRIMARY KEY, -- Message name
699 subject text, -- Message summary
700 template text, -- Message template
701 enabled bool NOT NULL DEFAULT true -- Whether message is enabled
704 --------------------------------------------------------------------------------
706 --------------------------------------------------------------------------------
709 CREATE TABLE event_types (
710 event_type text PRIMARY KEY -- Event type
712 INSERT INTO event_types (event_type) VALUES ('Add');
713 INSERT INTO event_types (event_type) VALUES ('AddTo');
714 INSERT INTO event_types (event_type) VALUES ('Get');
715 INSERT INTO event_types (event_type) VALUES ('Update');
716 INSERT INTO event_types (event_type) VALUES ('Delete');
717 INSERT INTO event_types (event_type) VALUES ('DeleteFrom');
718 INSERT INTO event_types (event_type) VALUES ('Unknown');
721 CREATE TABLE object_types (
722 object_type text PRIMARY KEY -- Object type
724 INSERT INTO object_types (object_type) VALUES ('AddressType');
725 INSERT INTO object_types (object_type) VALUES ('Address');
726 INSERT INTO object_types (object_type) VALUES ('BootState');
727 INSERT INTO object_types (object_type) VALUES ('ConfFile');
728 INSERT INTO object_types (object_type) VALUES ('KeyType');
729 INSERT INTO object_types (object_type) VALUES ('Key');
730 INSERT INTO object_types (object_type) VALUES ('Message');
731 INSERT INTO object_types (object_type) VALUES ('NetworkMethod');
732 INSERT INTO object_types (object_type) VALUES ('NetworkType');
733 INSERT INTO object_types (object_type) VALUES ('Network');
734 INSERT INTO object_types (object_type) VALUES ('NodeGroup');
735 INSERT INTO object_types (object_type) VALUES ('NodeNetwork');
736 INSERT INTO object_types (object_type) VALUES ('Node');
737 INSERT INTO object_types (object_type) VALUES ('PCU');
738 INSERT INTO object_types (object_type) VALUES ('Person');
739 INSERT INTO object_types (object_type) VALUES ('Role');
740 INSERT INTO object_types (object_type) VALUES ('Session');
741 INSERT INTO object_types (object_type) VALUES ('Site');
742 INSERT INTO object_types (object_type) VALUES ('SliceAttributeType');
743 INSERT INTO object_types (object_type) VALUES ('SliceAttribute');
744 INSERT INTO object_types (object_type) VALUES ('Slice');
745 INSERT INTO object_types (object_type) VALUES ('SliceInstantiation');
746 INSERT INTO object_types (object_type) VALUES ('Unknown');
749 CREATE TABLE events (
750 event_id serial PRIMARY KEY, -- Event identifier
751 person_id integer REFERENCES persons, -- Person responsible for event, if any
752 node_id integer REFERENCES nodes, -- Node responsible for event, if any
753 event_type text REFERENCES event_types NOT NULL DEFAULT 'Unknown', -- Event type
754 object_type text REFERENCES object_types NOT NULL DEFAULT 'Unknown', -- Object type associated with event
755 fault_code integer NOT NULL DEFAULT 0, -- Did this event result in error
756 call text NOT NULL, -- Call responsible for this event
757 runtime float, -- Event run time
758 time timestamp without time zone NOT NULL DEFAULT CURRENT_TIMESTAMP -- Event timestamp
762 CREATE TABLE event_object (
763 event_id integer REFERENCES events NOT NULL, -- Event identifier
764 object_id integer NOT NULL -- Object identifier
766 CREATE INDEX event_object_event_id_idx ON event_object (event_id);
767 CREATE INDEX event_object_object_id_idx ON event_object (object_id);
769 CREATE VIEW event_objects AS
771 array_accum(object_id) AS object_ids
775 --------------------------------------------------------------------------------
777 --------------------------------------------------------------------------------
779 CREATE VIEW view_events AS
789 CAST(date_part('epoch', events.time) AS bigint) AS time,
790 COALESCE(event_objects.object_ids, '{}') AS object_ids
792 LEFT JOIN event_objects USING (event_id);
794 CREATE VIEW view_persons AS
803 persons.verification_key,
804 persons.verification_expires,
810 CAST(date_part('epoch', persons.date_created) AS bigint) AS date_created,
811 CAST(date_part('epoch', persons.last_updated) AS bigint) AS last_updated,
812 COALESCE(person_roles.role_ids, '{}') AS role_ids,
813 COALESCE(person_roles.roles, '{}') AS roles,
814 COALESCE(person_sites.site_ids, '{}') AS site_ids,
815 COALESCE(person_keys.key_ids, '{}') AS key_ids,
816 COALESCE(person_slices.slice_ids, '{}') AS slice_ids
818 LEFT JOIN person_roles USING (person_id)
819 LEFT JOIN person_sites USING (person_id)
820 LEFT JOIN person_keys USING (person_id)
821 LEFT JOIN person_slices USING (person_id);
823 CREATE VIEW view_peers AS
827 peer_slices.slice_ids
829 LEFT JOIN peer_nodes USING (peer_id)
830 LEFT JOIN peer_slices USING (peer_id);
832 CREATE VIEW view_nodes AS
845 CAST(date_part('epoch', nodes.date_created) AS bigint) AS date_created,
846 CAST(date_part('epoch', nodes.last_updated) AS bigint) AS last_updated,
847 COALESCE(node_nodenetworks.nodenetwork_ids, '{}') AS nodenetwork_ids,
848 COALESCE(node_nodegroups.nodegroup_ids, '{}') AS nodegroup_ids,
849 COALESCE(node_slices.slice_ids, '{}') AS slice_ids,
850 COALESCE(node_pcus.pcu_ids, '{}') AS pcu_ids,
851 COALESCE(node_pcus.ports, '{}') AS ports,
852 COALESCE(node_conf_files.conf_file_ids, '{}') AS conf_file_ids,
853 node_session.session_id AS session
855 LEFT JOIN node_nodenetworks USING (node_id)
856 LEFT JOIN node_nodegroups USING (node_id)
857 LEFT JOIN node_slices USING (node_id)
858 LEFT JOIN node_pcus USING (node_id)
859 LEFT JOIN node_conf_files USING (node_id)
860 LEFT JOIN node_session USING (node_id);
862 CREATE VIEW view_nodegroups AS
864 nodegroups.nodegroup_id,
866 nodegroups.description,
867 COALESCE(nodegroup_nodes.node_ids, '{}') AS node_ids,
868 COALESCE(nodegroup_conf_files.conf_file_ids, '{}') AS conf_file_ids
870 LEFT JOIN nodegroup_nodes USING (nodegroup_id)
871 LEFT JOIN nodegroup_conf_files USING (nodegroup_id);
873 CREATE VIEW view_conf_files AS
875 conf_files.conf_file_id,
879 conf_files.file_permissions,
880 conf_files.file_owner,
881 conf_files.file_group,
882 conf_files.preinstall_cmd,
883 conf_files.postinstall_cmd,
884 conf_files.error_cmd,
885 conf_files.ignore_cmd_errors,
886 conf_files.always_update,
887 COALESCE(conf_file_nodes.node_ids, '{}') AS node_ids,
888 COALESCE(conf_file_nodegroups.nodegroup_ids, '{}') AS nodegroup_ids
890 LEFT JOIN conf_file_nodes USING (conf_file_id)
891 LEFT JOIN conf_file_nodegroups USING (conf_file_id);
893 CREATE VIEW view_pcus AS
904 COALESCE(pcu_nodes.node_ids, '{}') AS node_ids,
905 COALESCE(pcu_nodes.ports, '{}') AS ports
907 LEFT JOIN pcu_nodes USING (pcu_id);
909 CREATE VIEW view_sites AS
914 sites.abbreviated_name,
923 CAST(date_part('epoch', sites.date_created) AS bigint) AS date_created,
924 CAST(date_part('epoch', sites.last_updated) AS bigint) AS last_updated,
925 COALESCE(site_persons.person_ids, '{}') AS person_ids,
926 COALESCE(site_nodes.node_ids, '{}') AS node_ids,
927 COALESCE(site_addresses.address_ids, '{}') AS address_ids,
928 COALESCE(site_slices.slice_ids, '{}') AS slice_ids,
929 COALESCE(site_pcus.pcu_ids, '{}') AS pcu_ids
931 LEFT JOIN site_persons USING (site_id)
932 LEFT JOIN site_nodes USING (site_id)
933 LEFT JOIN site_addresses USING (site_id)
934 LEFT JOIN site_slices USING (site_id)
935 LEFT JOIN site_pcus USING (site_id);
937 CREATE VIEW view_addresses AS
939 addresses.address_id,
945 addresses.postalcode,
947 COALESCE(address_address_types.address_type_ids, '{}') AS address_type_ids,
948 COALESCE(address_address_types.address_types, '{}') AS address_types
950 LEFT JOIN address_address_types USING (address_id);
952 CREATE VIEW view_slices AS
958 slices.instantiation,
962 slices.creator_person_id,
964 CAST(date_part('epoch', slices.created) AS bigint) AS created,
965 CAST(date_part('epoch', slices.expires) AS bigint) AS expires,
966 COALESCE(slice_nodes.node_ids, '{}') AS node_ids,
967 COALESCE(slice_persons.person_ids, '{}') AS person_ids,
968 COALESCE(slice_attributes.slice_attribute_ids, '{}') AS slice_attribute_ids
970 LEFT JOIN slice_nodes USING (slice_id)
971 LEFT JOIN slice_persons USING (slice_id)
972 LEFT JOIN slice_attributes USING (slice_id);
975 CREATE VIEW view_slice_attributes AS
977 slice_attribute.slice_attribute_id,
978 slice_attribute.slice_id,
979 slice_attribute.node_id,
980 slice_attribute_types.attribute_type_id,
981 slice_attribute_types.name,
982 slice_attribute_types.description,
983 slice_attribute_types.min_role_id,
984 slice_attribute.value,
985 slice_attribute.peer_id
987 INNER JOIN slice_attribute_types USING (attribute_type_id);
989 CREATE VIEW view_sessions AS
992 CAST(date_part('epoch', sessions.expires) AS bigint) AS expires,
993 person_session.person_id,
996 LEFT JOIN person_session USING (session_id)
997 LEFT JOIN node_session USING (session_id);
999 --------------------------------------------------------------------------------
1000 -- Built-in maintenance account and default site
1001 --------------------------------------------------------------------------------
1004 (first_name, last_name, email, password, enabled)
1006 ('Maintenance', 'Account', 'maint@localhost.localdomain', 'nopass', true);
1008 INSERT INTO person_role (person_id, role_id) VALUES (1, 10);
1009 INSERT INTO person_role (person_id, role_id) VALUES (1, 20);
1010 INSERT INTO person_role (person_id, role_id) VALUES (1, 30);
1011 INSERT INTO person_role (person_id, role_id) VALUES (1, 40);
1014 (login_base, name, abbreviated_name, max_slices)
1016 ('pl', 'PlanetLab Central', 'PLC', 100);