From 69f3721e98d1b745ac1cbcb48e046f9a741a4070 Mon Sep 17 00:00:00 2001 From: Peter Hormanns Date: Mon, 10 Apr 2017 18:42:48 +0200 Subject: [PATCH] update sql scripts --- db-migration/database/hsdb-bootstrap.sql | 23 +- db-migration/database/hsdb-drop.sql | 43 ++ db-migration/database/hsdb-migrate.sql | 58 ++ db-migration/database/hsdb-schema.sql | 779 ++++++++++++++++------- db-migration/database/migrate.sql | 0 5 files changed, 648 insertions(+), 255 deletions(-) create mode 100644 db-migration/database/hsdb-drop.sql create mode 100644 db-migration/database/hsdb-migrate.sql delete mode 100644 db-migration/database/migrate.sql diff --git a/db-migration/database/hsdb-bootstrap.sql b/db-migration/database/hsdb-bootstrap.sql index 396ea9a..84ad030 100644 --- a/db-migration/database/hsdb-bootstrap.sql +++ b/db-migration/database/hsdb-bootstrap.sql @@ -73,13 +73,7 @@ INSERT INTO component (basepacket_id, basecomponent_id, min_quantity, max_quanti SELECT basepacket_id, basecomponent_id, 1, 16, 1, 1, 0, false, 420 FROM basepacket, basecomponent WHERE basepacket_code='SRV/MGD' AND basecomponent_code='CPU'; INSERT INTO component (basepacket_id, basecomponent_id, min_quantity, max_quantity, default_quantity, increment_quantity, include_quantity, admin_only, article_number) SELECT basepacket_id, basecomponent_id, 10, 1000, 10, 10, 0, false, 430 FROM basepacket, basecomponent WHERE basepacket_code='SRV/MGD' AND basecomponent_code='TRAFFIC'; - --- --- Table: role --- -INSERT INTO role (role_name) VALUES ('billing'); -INSERT INTO role (role_name) VALUES ('operation'); - + -- -- Table: business_partner -- @@ -90,16 +84,8 @@ INSERT INTO business_partner (member_id, member_code, member_since, shares_signe -- table: contact -- INSERT INTO contact (bp_id, salut, first_name, last_name, firma, email) - SELECT bp_id, 'Herr', 'Sigi', 'Superb', 'Hosting Inc.', 'info@example.com' FROM business_partner WHERE member_id=10000; + SELECT bp_id, 'Herr', 'Uwe', 'Mueller', 'Hostsharing eG', 'service@hostsharing.net' FROM business_partner WHERE member_id=10000; --- --- table: contactrole_ref --- -INSERT INTO contactrole_ref ( contact_id, role ) - SELECT contact_id, 'billing' FROM contact WHERE email='info@example.com'; -INSERT INTO contactrole_ref ( contact_id, role ) - SELECT contact_id, 'operation' FROM contact WHERE email='info@example.com'; - -- -- Table: inet_addr -- @@ -213,10 +199,11 @@ INSERT INTO domain_option (domain_option_name) -- -- table: price_list -- -INSERT INTO price_list VALUES (1, 'Default Price List'); +INSERT INTO price_list (name) VALUES ('Default Price List'); -- -- table: customer_price_list_mapping -- -INSERT INTO pricelist_ref (SELECT bp_id, 'Default Price List' FROM business_partner); +INSERT INTO pricelist_ref (SELECT business_partner.bp_id, price_list.name FROM business_partner, price_list); + diff --git a/db-migration/database/hsdb-drop.sql b/db-migration/database/hsdb-drop.sql new file mode 100644 index 0000000..cb73476 --- /dev/null +++ b/db-migration/database/hsdb-drop.sql @@ -0,0 +1,43 @@ +DROP TABLE pricelist_ref ; +DROP TABLE price ; +DROP TABLE price_list CASCADE ; +-- DROP VIEW business_partner_ticket ; +DROP TABLE sepa_mandat ; +DROP SEQUENCE sepa_mandat_id_seq ; +DROP SEQUENCE contact_contact_id_seq ; +DROP TABLE contact CASCADE ; +DROP TABLE database ; +DROP TABLE database_user ; +DROP SEQUENCE database_database_id_seq ; +DROP SEQUENCE dbuser_dbuser_id_seq ; +DROP TABLE emailaddr ; +DROP SEQUENCE emailaddr_emailaddr_id_seq ; +DROP TABLE emailalias ; +DROP SEQUENCE emailalias_emailalias_id_seq ; +DROP TABLE domain__domain_option ; +DROP TABLE domain_option ; +DROP SEQUENCE domain_option_id_seq ; +DROP TABLE domain ; +DROP SEQUENCE domain_domain_id_seq ; +DROP TABLE queue_task ; +DROP SEQUENCE queue_task_id_seq ; +DROP TABLE unixuser CASCADE ; +DROP SEQUENCE unixuser_unixuser_id_seq ; +DROP TABLE packet_component ; +DROP TABLE component ; +DROP TABLE basecomponent ; +DROP TABLE basepacket CASCADE ; +DROP SEQUENCE basecomponent_basecomponent_seq ; +DROP SEQUENCE basepacket_basepacket_id_seq ; +DROP TABLE packet ; +DROP SEQUENCE packet_packet_id_seq ; +DROP TABLE hive ; +DROP SEQUENCE hive_hive_id_seq ; +DROP TABLE inet_addr ; +DROP SEQUENCE inet_addr_inet_addr_id_seq ; +DROP TABLE business_partner CASCADE ; +DROP SEQUENCE business_partner_bp_id_seq ; +DROP SEQUENCE packet_component_id_seq ; +DROP SEQUENCE component_id_seq ; +DROP TABLE contactrole_ref CASCADE ; +DROP TABLE role CASCADE ; diff --git a/db-migration/database/hsdb-migrate.sql b/db-migration/database/hsdb-migrate.sql new file mode 100644 index 0000000..8935755 --- /dev/null +++ b/db-migration/database/hsdb-migrate.sql @@ -0,0 +1,58 @@ + +INSERT INTO contactrole_ref (contact_id, role) + ( SELECT contact_id, 'voting-right' FROM contact ); + +CREATE TABLE member_asset ( + member_asset_id integer NOT NULL, + bp_id integer NOT NULL, + date date, + action character varying(60), + amount numeric, + comment character varying(160) +); + +CREATE SEQUENCE member_asset_member_asset_id_seq + START WITH 1 + INCREMENT BY 1 + NO MINVALUE + NO MAXVALUE + CACHE 1; + +ALTER SEQUENCE member_asset_member_asset_id_seq OWNED BY member_asset.member_asset_id; + +ALTER TABLE ONLY member_asset ALTER COLUMN member_asset_id SET DEFAULT nextval('member_asset_member_asset_id_seq'::regclass); + +CREATE TABLE member_share ( + member_share_id integer NOT NULL, + bp_id integer NOT NULL, + date date, + action character varying(60), + quantity integer, + comment character varying(160) +); + +CREATE SEQUENCE member_share_member_share_id_seq + START WITH 1 + INCREMENT BY 1 + NO MINVALUE + NO MAXVALUE + CACHE 1; + +ALTER SEQUENCE member_share_member_share_id_seq OWNED BY member_share.member_share_id; + +ALTER TABLE ONLY member_share ALTER COLUMN member_share_id SET DEFAULT nextval('member_share_member_share_id_seq'::regclass); + +ALTER TABLE ONLY member_asset + ADD CONSTRAINT pk_member_asset PRIMARY KEY (member_asset_id); + +ALTER TABLE ONLY member_share + ADD CONSTRAINT pk_member_share PRIMARY KEY (member_share_id); + +ALTER TABLE ONLY member_asset + ADD CONSTRAINT pk_member_asset PRIMARY KEY (member_asset_id); + +ALTER TABLE business_partner DROP CONSTRAINT ckc_shares_signed_business; + +ALTER TABLE business_partner DROP COLUMN shares_updated ; + +ALTER TABLE business_partner DROP COLUMN shares_signed ; diff --git a/db-migration/database/hsdb-schema.sql b/db-migration/database/hsdb-schema.sql index c197418..8d4f02d 100644 --- a/db-migration/database/hsdb-schema.sql +++ b/db-migration/database/hsdb-schema.sql @@ -1,16 +1,37 @@ -CREATE SEQUENCE bank_account_bank_account_i_seq - START WITH 1 +CREATE SEQUENCE sepa_mandat_id_seq INCREMENT BY 1 - NO MINVALUE NO MAXVALUE + NO MINVALUE CACHE 1; -CREATE SEQUENCE bank_account_bank_account_id_seq - START WITH 1 - INCREMENT BY 1 - NO MINVALUE - NO MAXVALUE - CACHE 1; +CREATE TABLE sepa_mandat ( + sepa_mandat_id integer NOT NULL, + bp_id integer NOT NULL, + bank_customer character varying(50) NOT NULL, + bank_name character varying(50), + bank_iban character varying(40) NOT NULL, + bank_bic character varying(40) NOT NULL, + mandat_ref character varying(40) NOT NULL, + mandat_signed date NOT NULL, + mandat_since date NOT NULL, + mandat_used date, + mandat_until date +); + +ALTER TABLE ONLY sepa_mandat ALTER COLUMN sepa_mandat_id SET DEFAULT nextval('sepa_mandat_id_seq'::regclass); + +ALTER TABLE ONLY sepa_mandat + ADD CONSTRAINT pk_sepa_mandat PRIMARY KEY (sepa_mandat_id); + +ALTER TABLE ONLY sepa_mandat + ADD CONSTRAINT dateschk1 CHECK (mandat_signed <= mandat_since AND mandat_since <= mandat_until); + +ALTER TABLE ONLY sepa_mandat + ADD CONSTRAINT dateschk2 CHECK (mandat_since <= mandat_until AND mandat_since <= mandat_used AND mandat_used <= mandat_until); + +-- +-- Name: basecomponent; Type: TABLE; Schema: public; Owner: -; Tablespace: +-- CREATE TABLE basecomponent ( basecomponent_id integer DEFAULT nextval(('"basecomponent_basecomponent_seq"'::text)::regclass) NOT NULL, @@ -20,35 +41,43 @@ CREATE TABLE basecomponent ( valid boolean NOT NULL ); + +-- +-- Name: basecomponent_basecomponent_seq; Type: SEQUENCE; Schema: public; Owner: - +-- + CREATE SEQUENCE basecomponent_basecomponent_seq - START WITH 1 INCREMENT BY 1 - NO MINVALUE NO MAXVALUE + NO MINVALUE + CACHE 1; + + +-- +-- Name: basepacket; Type: TABLE; Schema: public; Owner: -; Tablespace: +-- + +CREATE SEQUENCE basepacket_basepacket_id_seq + INCREMENT BY 1 + NO MAXVALUE + NO MINVALUE CACHE 1; CREATE TABLE basepacket ( basepacket_id integer DEFAULT nextval(('"basepacket_basepacket_id_seq"'::text)::regclass) NOT NULL, basepacket_code character varying(10) NOT NULL, description character varying(100) NOT NULL, + article_number integer NOT NULL, sorting integer NOT NULL, - valid boolean NOT NULL, - article_number integer NOT NULL + valid boolean NOT NULL ); -CREATE SEQUENCE basepacket_basepacket_id_seq - START WITH 1 - INCREMENT BY 1 - NO MINVALUE - NO MAXVALUE - CACHE 1; +ALTER TABLE ONLY basepacket + ADD CONSTRAINT pk_basepacket PRIMARY KEY (basepacket_id); -CREATE SEQUENCE billdata_billdata_id_seq - START WITH 1 - INCREMENT BY 1 - NO MINVALUE - NO MAXVALUE - CACHE 1; +-- +-- Name: business_partner; Type: TABLE; Schema: public; Owner: -; Tablespace: +-- CREATE TABLE business_partner ( bp_id integer DEFAULT nextval(('"business_partner_bp_id_seq"'::text)::regclass) NOT NULL, @@ -62,21 +91,70 @@ CREATE TABLE business_partner ( shares_updated date, shares_signed integer NOT NULL, uid_vat character varying(20), - free boolean DEFAULT false NOT NULL, - indicator_vat character varying(20) DEFAULT 'GROSS'::character varying NOT NULL, - exempt_vat boolean DEFAULT false NOT NULL, + free boolean NOT NULL, + indicator_vat character varying(20) NOT NULL, + exempt_vat boolean NOT NULL, CONSTRAINT ckc_member_id_business CHECK (((member_id >= 10000) AND (member_id <= 99999))), CONSTRAINT ckc_shares_signed_business CHECK ((shares_signed >= 0)), - CONSTRAINT ckt_business_partner CHECK ((((((member_since IS NULL) AND (member_until IS NULL)) OR ((member_since IS NOT NULL) AND (member_until IS NULL))) OR (((member_since IS NOT NULL) AND (member_until IS NOT NULL)) AND (member_since < member_until))) AND ((member_code)::text ~~ 'hsh00-%'::text))) + CONSTRAINT ckt_business_partner CHECK ( ( ((member_since IS NULL) AND (member_until IS NULL)) OR ((member_since IS NOT NULL) AND (member_until IS NULL)) OR ((member_since IS NOT NULL) AND (member_until IS NOT NULL) AND (member_since < member_until)) ) AND ((member_code)::text ~~ 'hsh00-%'::text)), + UNIQUE (bp_id) ); + +-- +-- Name: business_partner_bp_id_seq; Type: SEQUENCE; Schema: public; Owner: - +-- + CREATE SEQUENCE business_partner_bp_id_seq - START WITH 1 INCREMENT BY 1 - NO MINVALUE NO MAXVALUE + NO MINVALUE CACHE 1; +ALTER TABLE ONLY sepa_mandat + ADD CONSTRAINT fk_bank_acc_reference_business FOREIGN KEY (bp_id) REFERENCES business_partner(bp_id) ON UPDATE RESTRICT ON DELETE RESTRICT; + + + +-- +-- Name: component; Type: TABLE; Schema: public; Owner: -; Tablespace: +-- + +CREATE SEQUENCE component_id_seq + INCREMENT BY 1 + NO MAXVALUE + NO MINVALUE + CACHE 1; + +CREATE TABLE component ( + component_id integer DEFAULT nextval(('"component_id_seq"'::text)::regclass) NOT NULL, + basepacket_id integer NOT NULL, + basecomponent_id integer NOT NULL, + article_number integer NOT NULL, + min_quantity integer NOT NULL, + max_quantity integer NOT NULL, + default_quantity integer NOT NULL, + increment_quantity integer NOT NULL, + include_quantity integer NOT NULL, + admin_only boolean NOT NULL, + CONSTRAINT ckt_component CHECK ( + (0 <= min_quantity) AND + (min_quantity <= default_quantity) AND + (default_quantity <= max_quantity) AND + (include_quantity <= default_quantity) AND + (0 <= include_quantity) AND + (mod(min_quantity, increment_quantity) = 0) AND + (mod(max_quantity, increment_quantity) = 0) AND + (mod(default_quantity, increment_quantity) = 0) AND + (mod(include_quantity, increment_quantity) = 0) + ) +); + + +-- +-- Name: contact; Type: TABLE; Schema: public; Owner: -; Tablespace: +-- + CREATE TABLE contact ( contact_id integer DEFAULT nextval(('"contact_contact_id_seq"'::text)::regclass) NOT NULL, bp_id integer NOT NULL, @@ -98,35 +176,17 @@ CREATE TABLE contact ( CONSTRAINT ckc_email_contact CHECK (((email)::text ~~ '%@%.%'::text)) ); -CREATE VIEW business_partner_ticket AS - SELECT (business_partner.member_id)::character varying(20) AS member_id, "substring"((business_partner.member_code)::text, 7) AS member_code, contact.salut, contact.first_name, contact.last_name, contact.title, contact.firma, contact.co, contact.street, contact.zipcode, contact.city, contact.country, contact.phone_private, contact.phone_office, contact.phone_mobile, contact.fax, contact.email, ((COALESCE(to_char((business_partner.member_since)::timestamp with time zone, 'YYYY-DD-MM'::text), '-'::text) || ' / '::text) || COALESCE(to_char((business_partner.member_until)::timestamp with time zone, 'YYYY-DD-MM'::text), '-'::text)) AS comment, 1 AS valid FROM (business_partner LEFT JOIN contact ON ((contact.bp_id = business_partner.bp_id))) ORDER BY (business_partner.member_id)::character varying(20); - -CREATE TABLE component ( - basepacket_id integer NOT NULL, - basecomponent_id integer NOT NULL, - min_quantity integer NOT NULL, - max_quantity integer NOT NULL, - default_quantity integer NOT NULL, - increment_quantity integer NOT NULL, - include_quantity integer NOT NULL, - admin_only boolean NOT NULL, - article_number integer NOT NULL, - component_id integer DEFAULT nextval(('"component_id_seq"'::text)::regclass) NOT NULL, - CONSTRAINT ckt_component CHECK ((((((((((0 <= min_quantity) AND (min_quantity <= default_quantity)) AND (default_quantity <= max_quantity)) AND (include_quantity <= default_quantity)) AND (0 <= include_quantity)) AND (mod(min_quantity, increment_quantity) = 0)) AND (mod(max_quantity, increment_quantity) = 0)) AND (mod(default_quantity, increment_quantity) = 0)) AND (mod(include_quantity, increment_quantity) = 0))) -); - -CREATE SEQUENCE component_id_seq - START WITH 1 - INCREMENT BY 1 - NO MINVALUE - NO MAXVALUE - CACHE 1; +ALTER TABLE ONLY contact + ADD CONSTRAINT pk_contact PRIMARY KEY (contact_id); + +-- +-- Name: contact_contact_id_seq; Type: SEQUENCE; Schema: public; Owner: - +-- CREATE SEQUENCE contact_contact_id_seq - START WITH 1 INCREMENT BY 1 - NO MINVALUE NO MAXVALUE + NO MINVALUE CACHE 1; CREATE TABLE contactrole_ref ( @@ -134,13 +194,77 @@ CREATE TABLE contactrole_ref ( role character varying(40) NOT NULL ); +ALTER TABLE ONLY contactrole_ref + ADD CONSTRAINT pk_contactrole_ref PRIMARY KEY (contact_id, role); + +CREATE TABLE role ( + role_name character varying(40) NOT NULL +); + +ALTER TABLE ONLY role + ADD CONSTRAINT pk_role PRIMARY KEY (role_name); + +INSERT INTO role VALUES ('billing'), ('operations'); + +ALTER TABLE ONLY contactrole_ref + ADD CONSTRAINT fk_contactrole_ref_role FOREIGN KEY (role) REFERENCES role(role_name); + +ALTER TABLE ONLY contactrole_ref + ADD CONSTRAINT fk_contactrole_ref_contact FOREIGN KEY (contact_id) REFERENCES contact(contact_id); + +INSERT INTO contactrole_ref (contact_id, role) + ( SELECT contact_id, 'billing' FROM contact ); + +INSERT INTO contactrole_ref (contact_id, role) + ( SELECT contact_id, 'operations' FROM contact ); + +CREATE TABLE price_list ( + id serial primary key, + name character varying(20) +); + +ALTER TABLE price_list + ADD CONSTRAINT price_list_uniq_name UNIQUE (name); + +CREATE TABLE pricelist_ref ( + bp_id integer NOT NULL, + price_list character varying(40) NOT NULL +); + +ALTER TABLE ONLY pricelist_ref + ADD CONSTRAINT fk_pricelist_ref_bp FOREIGN KEY (bp_id) REFERENCES business_partner(bp_id) ON UPDATE RESTRICT ON DELETE CASCADE; + +ALTER TABLE ONLY pricelist_ref + ADD CONSTRAINT fk_pricelist_ref_pricelist FOREIGN KEY (price_list) REFERENCES price_list(name) ON UPDATE RESTRICT ON DELETE CASCADE; + + +-- +-- Name: price +-- + +CREATE TABLE price ( + id serial primary key, + article_number integer NOT NULL, + price decimal(10, 2) NOT NULL, + vat decimal(4,2) NOT NULL, + price_list integer references price_list(id) +); + +-- +-- Name: database_database_id_seq; Type: SEQUENCE; Schema: public; Owner: - +-- + CREATE SEQUENCE database_database_id_seq - START WITH 1 INCREMENT BY 1 - NO MINVALUE NO MAXVALUE + NO MINVALUE CACHE 1; + +-- +-- Name: database; Type: TABLE; Schema: public; Owner: -; Tablespace: +-- + CREATE TABLE database ( database_id integer DEFAULT nextval('database_database_id_seq'::regclass) NOT NULL, engine character varying(12) NOT NULL, @@ -150,13 +274,22 @@ CREATE TABLE database ( encoding character varying(12) NOT NULL ); + +-- +-- Name: dbuser_dbuser_id_seq; Type: SEQUENCE; Schema: public; Owner: - +-- + CREATE SEQUENCE dbuser_dbuser_id_seq - START WITH 1 INCREMENT BY 1 - NO MINVALUE NO MAXVALUE + NO MINVALUE CACHE 1; + +-- +-- Name: database_user; Type: TABLE; Schema: public; Owner: -; Tablespace: +-- + CREATE TABLE database_user ( dbuser_id integer DEFAULT nextval('dbuser_dbuser_id_seq'::regclass) NOT NULL, engine character varying(12) NOT NULL, @@ -164,13 +297,22 @@ CREATE TABLE database_user ( name character varying(64) NOT NULL ); + +-- +-- Name: domain_domain_id_seq; Type: SEQUENCE; Schema: public; Owner: - +-- + CREATE SEQUENCE domain_domain_id_seq - START WITH 1 INCREMENT BY 1 - NO MINVALUE NO MAXVALUE + NO MINVALUE CACHE 1; + +-- +-- Name: domain; Type: TABLE; Schema: public; Owner: -; Tablespace: +-- + CREATE TABLE domain ( domain_name character varying(256) NOT NULL, domain_since date, @@ -179,30 +321,22 @@ CREATE TABLE domain ( domain_owner integer NOT NULL ); -CREATE TABLE domain__domain_option ( - domain_option_id integer NOT NULL, - domain_id integer NOT NULL -); -CREATE TABLE domain_option ( - domain_option_id integer DEFAULT nextval(('"domain_option_id_seq"'::text)::regclass) NOT NULL, - domain_option_name character varying(50) NOT NULL -); - -CREATE SEQUENCE domain_option_id_seq - START WITH 1 - INCREMENT BY 1 - NO MINVALUE - NO MAXVALUE - CACHE 1; +-- +-- Name: emailaddr_emailaddr_id_seq; Type: SEQUENCE; Schema: public; Owner: - +-- CREATE SEQUENCE emailaddr_emailaddr_id_seq - START WITH 1 INCREMENT BY 1 - NO MINVALUE NO MAXVALUE + NO MINVALUE CACHE 1; + +-- +-- Name: emailaddr; Type: TABLE; Schema: public; Owner: -; Tablespace: +-- + CREATE TABLE emailaddr ( emailaddr_id integer DEFAULT nextval('emailaddr_emailaddr_id_seq'::regclass) NOT NULL, localpart character varying(64) NOT NULL, @@ -211,13 +345,22 @@ CREATE TABLE emailaddr ( subdomain character varying(64) ); + +-- +-- Name: emailalias_emailalias_id_seq; Type: SEQUENCE; Schema: public; Owner: - +-- + CREATE SEQUENCE emailalias_emailalias_id_seq - START WITH 1 INCREMENT BY 1 - NO MINVALUE NO MAXVALUE + NO MINVALUE CACHE 1; + +-- +-- Name: emailalias; Type: TABLE; Schema: public; Owner: -; Tablespace: +-- + CREATE TABLE emailalias ( emailalias_id integer DEFAULT nextval('emailalias_emailalias_id_seq'::regclass) NOT NULL, pac_id integer NOT NULL, @@ -225,6 +368,11 @@ CREATE TABLE emailalias ( name character varying(96) NOT NULL ); + +-- +-- Name: hive; Type: TABLE; Schema: public; Owner: -; Tablespace: +-- + CREATE TABLE hive ( hive_id integer DEFAULT nextval(('"hive_hive_id_seq"'::text)::regclass) NOT NULL, hive_name character varying(3) NOT NULL, @@ -232,13 +380,22 @@ CREATE TABLE hive ( description character varying(100) ); + +-- +-- Name: hive_hive_id_seq; Type: SEQUENCE; Schema: public; Owner: - +-- + CREATE SEQUENCE hive_hive_id_seq - START WITH 1 INCREMENT BY 1 - NO MINVALUE NO MAXVALUE + NO MINVALUE CACHE 1; + +-- +-- Name: inet_addr; Type: TABLE; Schema: public; Owner: -; Tablespace: +-- + CREATE TABLE inet_addr ( inet_addr_id integer DEFAULT nextval(('"inet_addr_inet_addr_id_seq"'::text)::regclass) NOT NULL, inet_addr inet NOT NULL, @@ -246,110 +403,70 @@ CREATE TABLE inet_addr ( CONSTRAINT ckc_inet_addr_inet_add CHECK ((masklen(inet_addr) = 32)) ); + +-- +-- Name: inet_addr_inet_addr_id_seq; Type: SEQUENCE; Schema: public; Owner: - +-- + CREATE SEQUENCE inet_addr_inet_addr_id_seq - START WITH 1 INCREMENT BY 1 - NO MINVALUE NO MAXVALUE + NO MINVALUE CACHE 1; -CREATE SEQUENCE member_id_seq - START WITH 10200 + +-- +-- Name: packet; Type: TABLE; Schema: public; Owner: -; Tablespace: +-- + +CREATE SEQUENCE packet_packet_id_seq INCREMENT BY 1 - MINVALUE 10200 - MAXVALUE 99999 + NO MAXVALUE + NO MINVALUE CACHE 1; CREATE TABLE packet ( packet_id integer DEFAULT nextval(('"packet_packet_id_seq"'::text)::regclass) NOT NULL, + basepacket_id integer NOT NULL, packet_name character varying(5) NOT NULL, bp_id integer NOT NULL, hive_id integer NOT NULL, created date NOT NULL, cancelled date, + free boolean NOT NULL, cur_inet_addr_id integer, old_inet_addr_id integer, - free boolean DEFAULT false NOT NULL, - basepacket_id integer, CONSTRAINT ckt_packet CHECK (((cancelled IS NULL) OR (cancelled > created))) ); +ALTER TABLE ONLY packet + ADD CONSTRAINT base_packet_ref FOREIGN KEY (basepacket_id) REFERENCES basepacket(basepacket_id); + + +-- +-- Name: packet_component; Type: TABLE; Schema: public; Owner: -; Tablespace: +-- + +CREATE SEQUENCE packet_component_id_seq + INCREMENT BY 1 + NO MAXVALUE + NO MINVALUE + CACHE 1; + CREATE TABLE packet_component ( + packet_component_id integer DEFAULT nextval(('"packet_component_id_seq"'::text)::regclass) NOT NULL, basecomponent_id integer NOT NULL, packet_id integer NOT NULL, quantity integer NOT NULL, created date, cancelled date, - packet_component_id integer DEFAULT nextval(('"packet_component_id_seq"'::text)::regclass) NOT NULL, CONSTRAINT ckt_packet_component CHECK (((cancelled IS NULL) OR (cancelled > created))) ); -CREATE SEQUENCE packet_component_id_seq - START WITH 1 - INCREMENT BY 1 - NO MINVALUE - NO MAXVALUE - CACHE 1; -CREATE SEQUENCE packet_packet_id_seq - START WITH 1 - INCREMENT BY 1 - NO MINVALUE - NO MAXVALUE - CACHE 1; - -CREATE TABLE price ( - id integer NOT NULL, - article_number integer NOT NULL, - price numeric(10,2) NOT NULL, - vat numeric(4,2) NOT NULL, - price_list integer -); - -CREATE SEQUENCE price_id_seq - START WITH 1 - INCREMENT BY 1 - NO MINVALUE - NO MAXVALUE - CACHE 1; - -ALTER SEQUENCE price_id_seq OWNED BY price.id; - -CREATE TABLE price_list ( - id integer NOT NULL, - name character varying(20) -); - -CREATE SEQUENCE price_list_id_seq - START WITH 1 - INCREMENT BY 1 - NO MINVALUE - NO MAXVALUE - CACHE 1; - -ALTER SEQUENCE price_list_id_seq OWNED BY price_list.id; - -CREATE TABLE pricelist_ref ( - bp_id integer NOT NULL, - price_list character varying(40) NOT NULL -); - -CREATE TABLE queue ( - queue_entry_id integer DEFAULT nextval(('"queue_queue_entry_id_seq"'::text)::regclass) NOT NULL, - user_id integer NOT NULL, - started timestamp without time zone NOT NULL, - finished timestamp without time zone, - title character varying(192), - details text, - CONSTRAINT ckt_queue CHECK (((finished IS NULL) OR (finished >= started))) -); - -CREATE SEQUENCE queue_queue_entry_id_seq - START WITH 1 - INCREMENT BY 1 - NO MINVALUE - NO MAXVALUE - CACHE 1; +-- +-- Name: queue_task; Type: TABLE; Schema: public; Owner: -; Tablespace: +-- CREATE TABLE queue_task ( task_id integer DEFAULT nextval(('"queue_task_id_seq"'::text)::regclass) NOT NULL, @@ -362,47 +479,33 @@ CREATE TABLE queue_task ( user_id integer ); + +-- +-- Name: queue_task_id_seq; Type: SEQUENCE; Schema: public; Owner: - +-- + CREATE SEQUENCE queue_task_id_seq - START WITH 1 INCREMENT BY 1 - NO MINVALUE NO MAXVALUE + NO MINVALUE CACHE 1; -CREATE TABLE role ( - role_name character varying(40) NOT NULL -); -CREATE TABLE sepa_mandat ( - sepa_mandat_id integer DEFAULT nextval(('"sepa_mandat_id_seq"'::text)::regclass) NOT NULL, - bp_id integer NOT NULL, - bank_customer character varying(50) NOT NULL, - bank_name character varying(50), - bank_iban character varying(40) NOT NULL, - bank_bic character varying(40) NOT NULL, - mandat_ref character varying(40) NOT NULL, - mandat_signed date NOT NULL, - mandat_since date NOT NULL, - mandat_used date, - mandat_until date, - CONSTRAINT dateschk1 CHECK (((mandat_signed <= mandat_since) AND (mandat_since <= mandat_until))), - CONSTRAINT dateschk2 CHECK ((((mandat_since <= mandat_until) AND (mandat_since <= mandat_used)) AND (mandat_used <= mandat_until))) -); - -CREATE SEQUENCE sepa_mandat_id_seq - START WITH 1 - INCREMENT BY 1 - NO MINVALUE - NO MAXVALUE - CACHE 1; +-- +-- Name: unixuser_unixuser_id_seq; Type: SEQUENCE; Schema: public; Owner: - +-- CREATE SEQUENCE unixuser_unixuser_id_seq - START WITH 1 INCREMENT BY 1 - NO MINVALUE NO MAXVALUE + NO MINVALUE CACHE 1; + +-- +-- Name: unixuser; Type: TABLE; Schema: public; Owner: -; Tablespace: +-- + CREATE TABLE unixuser ( unixuser_id integer DEFAULT nextval('unixuser_unixuser_id_seq'::regclass) NOT NULL, name character varying(64) NOT NULL, @@ -417,199 +520,401 @@ CREATE TABLE unixuser ( CONSTRAINT unixuser_userid CHECK ((userid >= 10000)) ); -ALTER TABLE ONLY price ALTER COLUMN id SET DEFAULT nextval('price_id_seq'::regclass); -ALTER TABLE ONLY price_list ALTER COLUMN id SET DEFAULT nextval('price_list_id_seq'::regclass); - -ALTER TABLE ONLY business_partner - ADD CONSTRAINT business_partner_bp_id_key UNIQUE (bp_id); +-- +-- Name: database_uniq; Type: CONSTRAINT; Schema: public; Owner: -; Tablespace: +-- ALTER TABLE ONLY database ADD CONSTRAINT database_uniq UNIQUE (engine, name); + +-- +-- Name: database_user_uniq; Type: CONSTRAINT; Schema: public; Owner: -; Tablespace: +-- + ALTER TABLE ONLY database_user ADD CONSTRAINT database_user_uniq UNIQUE (engine, name); + +-- +-- Name: emailaddr_uniq; Type: CONSTRAINT; Schema: public; Owner: -; Tablespace: +-- + ALTER TABLE ONLY emailaddr ADD CONSTRAINT emailaddr_uniq UNIQUE (localpart, subdomain, domain_id); -ALTER TABLE ONLY emailalias - ADD CONSTRAINT emailalias_pkey PRIMARY KEY (emailalias_id); + +-- +-- Name: emailalias_uniq; Type: CONSTRAINT; Schema: public; Owner: -; Tablespace: +-- ALTER TABLE ONLY emailalias ADD CONSTRAINT emailalias_uniq UNIQUE (name); + +-- +-- Name: pk_basecomponent; Type: CONSTRAINT; Schema: public; Owner: -; Tablespace: +-- + ALTER TABLE ONLY basecomponent ADD CONSTRAINT pk_basecomponent PRIMARY KEY (basecomponent_id); -ALTER TABLE ONLY basepacket - ADD CONSTRAINT pk_basepacket PRIMARY KEY (basepacket_id); + +-- +-- Name: pk_business_partner; Type: CONSTRAINT; Schema: public; Owner: -; Tablespace: +-- ALTER TABLE ONLY business_partner ADD CONSTRAINT pk_business_partner PRIMARY KEY (bp_id); + +-- +-- Name: pk_component; Type: CONSTRAINT; Schema: public; Owner: -; Tablespace: +-- + ALTER TABLE ONLY component ADD CONSTRAINT pk_component PRIMARY KEY (component_id); -ALTER TABLE ONLY contact - ADD CONSTRAINT pk_contact PRIMARY KEY (contact_id); - -ALTER TABLE ONLY contactrole_ref - ADD CONSTRAINT pk_contactrole_ref PRIMARY KEY (contact_id, role); - ALTER TABLE ONLY database ADD CONSTRAINT pk_database PRIMARY KEY (database_id); + +-- +-- Name: pk_database_user; Type: CONSTRAINT; Schema: public; Owner: -; Tablespace: +-- + ALTER TABLE ONLY database_user ADD CONSTRAINT pk_database_user PRIMARY KEY (dbuser_id); -ALTER TABLE ONLY domain__domain_option - ADD CONSTRAINT pk_domain__domain_option PRIMARY KEY (domain_option_id, domain_id); -ALTER TABLE ONLY domain_option - ADD CONSTRAINT pk_domain_option PRIMARY KEY (domain_option_id); +-- +-- Name: pk_hive; Type: CONSTRAINT; Schema: public; Owner: -; Tablespace: +-- ALTER TABLE ONLY hive ADD CONSTRAINT pk_hive PRIMARY KEY (hive_id); + +-- +-- Name: pk_inet_addr; Type: CONSTRAINT; Schema: public; Owner: -; Tablespace: +-- + ALTER TABLE ONLY inet_addr ADD CONSTRAINT pk_inet_addr PRIMARY KEY (inet_addr_id); + +-- +-- Name: pk_packet; Type: CONSTRAINT; Schema: public; Owner: -; Tablespace: +-- + ALTER TABLE ONLY packet ADD CONSTRAINT pk_packet PRIMARY KEY (packet_id); + +-- +-- Name: pk_packet_component; Type: CONSTRAINT; Schema: public; Owner: -; Tablespace: +-- + ALTER TABLE ONLY packet_component ADD CONSTRAINT pk_packet_component PRIMARY KEY (packet_component_id); -ALTER TABLE ONLY role - ADD CONSTRAINT pk_role PRIMARY KEY (role_name); -ALTER TABLE ONLY sepa_mandat - ADD CONSTRAINT pk_sepa_mandat PRIMARY KEY (sepa_mandat_id); +-- +-- Name: pk_unixuser; Type: CONSTRAINT; Schema: public; Owner: -; Tablespace: +-- ALTER TABLE ONLY unixuser ADD CONSTRAINT pk_unixuser PRIMARY KEY (unixuser_id); -ALTER TABLE ONLY price_list - ADD CONSTRAINT price_list_pkey PRIMARY KEY (id); -ALTER TABLE ONLY price_list - ADD CONSTRAINT price_list_uniq_name UNIQUE (name); - -ALTER TABLE ONLY price - ADD CONSTRAINT price_pkey PRIMARY KEY (id); +-- +-- Name: unixuser_name_key; Type: CONSTRAINT; Schema: public; Owner: -; Tablespace: +-- ALTER TABLE ONLY unixuser ADD CONSTRAINT unixuser_name_key UNIQUE (name); + +-- +-- Name: basecomponent_in_1; Type: INDEX; Schema: public; Owner: -; Tablespace: +-- + CREATE UNIQUE INDEX basecomponent_in_1 ON basecomponent USING btree (basecomponent_code); + +-- +-- Name: basepacket_in_1; Type: INDEX; Schema: public; Owner: -; Tablespace: +-- + CREATE UNIQUE INDEX basepacket_in_1 ON basepacket USING btree (basepacket_code); + +-- +-- Name: component_in_1; Type: INDEX; Schema: public; Owner: -; Tablespace: +-- + CREATE INDEX component_in_1 ON component USING btree (basecomponent_id); + +-- +-- Name: contact_in_1; Type: INDEX; Schema: public; Owner: -; Tablespace: +-- + CREATE INDEX contact_in_1 ON contact USING btree (bp_id); + +-- +-- Name: customer_in_1; Type: INDEX; Schema: public; Owner: -; Tablespace: +-- + CREATE UNIQUE INDEX customer_in_1 ON business_partner USING btree (member_code); + +-- +-- Name: customer_in_2; Type: INDEX; Schema: public; Owner: -; Tablespace: +-- + CREATE UNIQUE INDEX customer_in_2 ON business_partner USING btree (member_id); + +-- +-- Name: database_unique_owner; Type: INDEX; Schema: public; Owner: -; Tablespace: +-- + CREATE UNIQUE INDEX database_unique_owner ON database_user USING btree (name, engine); -CREATE UNIQUE INDEX domain_option_name_idx ON domain_option USING btree (domain_option_name); + +-- +-- Name: domain_unique_id; Type: INDEX; Schema: public; Owner: -; Tablespace: +-- CREATE UNIQUE INDEX domain_unique_id ON domain USING btree (domain_id); + +-- +-- Name: domain_unique_name; Type: INDEX; Schema: public; Owner: -; Tablespace: +-- + CREATE UNIQUE INDEX domain_unique_name ON domain USING btree (domain_name); + +-- +-- Name: emailaddr_uniq2; Type: INDEX; Schema: public; Owner: -; Tablespace: +-- + CREATE UNIQUE INDEX emailaddr_uniq2 ON emailaddr USING btree (localpart, domain_id) WHERE (subdomain IS NULL); + +-- +-- Name: hive_in_1; Type: INDEX; Schema: public; Owner: -; Tablespace: +-- + CREATE UNIQUE INDEX hive_in_1 ON hive USING btree (hive_name); + +-- +-- Name: inet_addr_in_1; Type: INDEX; Schema: public; Owner: -; Tablespace: +-- + CREATE UNIQUE INDEX inet_addr_in_1 ON inet_addr USING btree (inet_addr); + +-- +-- Name: packet_component_in_1; Type: INDEX; Schema: public; Owner: -; Tablespace: +-- + CREATE INDEX packet_component_in_1 ON packet_component USING btree (packet_id); + +-- +-- Name: packet_component_in_2; Type: INDEX; Schema: public; Owner: -; Tablespace: +-- + CREATE INDEX packet_component_in_2 ON packet_component USING btree (basecomponent_id); + +-- +-- Name: packet_in_1; Type: INDEX; Schema: public; Owner: -; Tablespace: +-- + CREATE UNIQUE INDEX packet_in_1 ON packet USING btree (packet_name); + +-- +-- Name: packet_in_2; Type: INDEX; Schema: public; Owner: -; Tablespace: +-- + CREATE INDEX packet_in_2 ON packet USING btree (bp_id); -ALTER TABLE ONLY packet - ADD CONSTRAINT base_packet_ref FOREIGN KEY (basepacket_id) REFERENCES basepacket(basepacket_id); + +-- +-- Name: unique_task_id; Type: INDEX; Schema: public; Owner: -; Tablespace: +-- + +CREATE UNIQUE INDEX unique_task_id ON queue_task USING btree (task_id); + + +-- +-- Name: database_owner; Type: FK CONSTRAINT; Schema: public; Owner: - +-- ALTER TABLE ONLY database ADD CONSTRAINT database_owner FOREIGN KEY (owner, engine) REFERENCES database_user(name, engine); + +-- +-- Name: database_packet_id_fkey; Type: FK CONSTRAINT; Schema: public; Owner: - +-- + ALTER TABLE ONLY database ADD CONSTRAINT database_packet_id_fkey FOREIGN KEY (packet_id) REFERENCES packet(packet_id) DEFERRABLE; + +-- +-- Name: dbuser_packet_id_fkey; Type: FK CONSTRAINT; Schema: public; Owner: - +-- + ALTER TABLE ONLY database_user ADD CONSTRAINT dbuser_packet_id_fkey FOREIGN KEY (packet_id) REFERENCES packet(packet_id) DEFERRABLE; -ALTER TABLE ONLY domain__domain_option - ADD CONSTRAINT domain_id_fkey FOREIGN KEY (domain_id) REFERENCES domain(domain_id) DEFERRABLE; -ALTER TABLE ONLY domain__domain_option - ADD CONSTRAINT domain_option_id_fkey FOREIGN KEY (domain_option_id) REFERENCES domain_option(domain_option_id) DEFERRABLE; +-- +-- Name: domain_owner_chk; Type: FK CONSTRAINT; Schema: public; Owner: - +-- ALTER TABLE ONLY domain ADD CONSTRAINT domain_owner_chk FOREIGN KEY (domain_owner) REFERENCES unixuser(unixuser_id) MATCH FULL; + +-- +-- Name: email_domain; Type: FK CONSTRAINT; Schema: public; Owner: - +-- + ALTER TABLE ONLY emailaddr ADD CONSTRAINT email_domain FOREIGN KEY (domain_id) REFERENCES domain(domain_id); + +-- +-- Name: emailalias_pac_id_fkey; Type: FK CONSTRAINT; Schema: public; Owner: - +-- + ALTER TABLE ONLY emailalias ADD CONSTRAINT emailalias_pac_id_fkey FOREIGN KEY (pac_id) REFERENCES packet(packet_id) DEFERRABLE; -ALTER TABLE ONLY sepa_mandat - ADD CONSTRAINT fk_bank_acc_reference_business FOREIGN KEY (bp_id) REFERENCES business_partner(bp_id) ON UPDATE RESTRICT ON DELETE RESTRICT; + +-- +-- Name: fk_bcomp_bpack; Type: FK CONSTRAINT; Schema: public; Owner: - +-- ALTER TABLE ONLY component ADD CONSTRAINT fk_bcomp_bpack FOREIGN KEY (basepacket_id) REFERENCES basepacket(basepacket_id) ON UPDATE RESTRICT ON DELETE RESTRICT; + +-- +-- Name: fk_comp_pack; Type: FK CONSTRAINT; Schema: public; Owner: - +-- + ALTER TABLE ONLY packet_component ADD CONSTRAINT fk_comp_pack FOREIGN KEY (packet_id) REFERENCES packet(packet_id) ON UPDATE RESTRICT ON DELETE RESTRICT; + +-- +-- Name: fk_contact_reference_business; Type: FK CONSTRAINT; Schema: public; Owner: - +-- + ALTER TABLE ONLY contact ADD CONSTRAINT fk_contact_reference_business FOREIGN KEY (bp_id) REFERENCES business_partner(bp_id) ON UPDATE RESTRICT ON DELETE RESTRICT; -ALTER TABLE ONLY contactrole_ref - ADD CONSTRAINT fk_contactrole_ref_contact FOREIGN KEY (contact_id) REFERENCES contact(contact_id); -ALTER TABLE ONLY contactrole_ref - ADD CONSTRAINT fk_contactrole_ref_role FOREIGN KEY (role) REFERENCES role(role_name); +-- +-- Name: fk_hive_inet; Type: FK CONSTRAINT; Schema: public; Owner: - +-- ALTER TABLE ONLY hive ADD CONSTRAINT fk_hive_inet FOREIGN KEY (inet_addr_id) REFERENCES inet_addr(inet_addr_id) ON UPDATE RESTRICT ON DELETE RESTRICT; + +-- +-- Name: fk_pac_cur_inet; Type: FK CONSTRAINT; Schema: public; Owner: - +-- + ALTER TABLE ONLY packet ADD CONSTRAINT fk_pac_cur_inet FOREIGN KEY (cur_inet_addr_id) REFERENCES inet_addr(inet_addr_id) ON UPDATE RESTRICT ON DELETE RESTRICT; + +-- +-- Name: fk_pac_old_inet; Type: FK CONSTRAINT; Schema: public; Owner: - +-- + ALTER TABLE ONLY packet ADD CONSTRAINT fk_pac_old_inet FOREIGN KEY (old_inet_addr_id) REFERENCES inet_addr(inet_addr_id) ON UPDATE RESTRICT ON DELETE RESTRICT; + +-- +-- Name: fk_packet_bp; Type: FK CONSTRAINT; Schema: public; Owner: - +-- + ALTER TABLE ONLY packet ADD CONSTRAINT fk_packet_bp FOREIGN KEY (bp_id) REFERENCES business_partner(bp_id) ON UPDATE RESTRICT ON DELETE RESTRICT; + +-- +-- Name: fk_packet_hive; Type: FK CONSTRAINT; Schema: public; Owner: - +-- + ALTER TABLE ONLY packet ADD CONSTRAINT fk_packet_hive FOREIGN KEY (hive_id) REFERENCES hive(hive_id) ON UPDATE RESTRICT ON DELETE RESTRICT; -ALTER TABLE ONLY pricelist_ref - ADD CONSTRAINT fk_pricelist_ref_bp FOREIGN KEY (bp_id) REFERENCES business_partner(bp_id) ON UPDATE RESTRICT ON DELETE CASCADE; -ALTER TABLE ONLY pricelist_ref - ADD CONSTRAINT fk_pricelist_ref_pricelist FOREIGN KEY (price_list) REFERENCES price_list(name) ON UPDATE RESTRICT ON DELETE CASCADE; +-- +-- Name: fk_reference_13; Type: FK CONSTRAINT; Schema: public; Owner: - +-- ALTER TABLE ONLY component ADD CONSTRAINT fk_reference_13 FOREIGN KEY (basecomponent_id) REFERENCES basecomponent(basecomponent_id) ON UPDATE RESTRICT ON DELETE RESTRICT; -ALTER TABLE ONLY price - ADD CONSTRAINT price_price_list_fkey FOREIGN KEY (price_list) REFERENCES price_list(id); + +-- +-- Name: queue_task_user_id_fkey; Type: FK CONSTRAINT; Schema: public; Owner: - +-- ALTER TABLE ONLY queue_task ADD CONSTRAINT queue_task_user_id_fkey FOREIGN KEY (user_id) REFERENCES unixuser(unixuser_id) ON DELETE SET NULL; -ALTER TABLE ONLY queue - ADD CONSTRAINT queue_user_id_fkey FOREIGN KEY (user_id) REFERENCES unixuser(unixuser_id) DEFERRABLE; +-- +-- domain options +-- + +CREATE SEQUENCE domain_option_id_seq + INCREMENT BY 1 + NO MAXVALUE + NO MINVALUE + CACHE 1; + +CREATE TABLE domain_option ( + domain_option_id integer DEFAULT nextval(('"domain_option_id_seq"'::text)::regclass) NOT NULL, + domain_option_name character varying(50) NOT NULL +); + +ALTER TABLE ONLY domain_option + ADD CONSTRAINT pk_domain_option PRIMARY KEY (domain_option_id); + +CREATE UNIQUE INDEX domain_option_name_idx ON domain_option USING btree ( domain_option_name ); + +CREATE TABLE domain__domain_option ( + domain_option_id integer NOT NULL, + domain_id integer NOT NULL +); + +ALTER TABLE ONLY domain__domain_option + ADD CONSTRAINT pk_domain__domain_option PRIMARY KEY (domain_option_id, domain_id); + +ALTER TABLE ONLY domain__domain_option + ADD CONSTRAINT domain_option_id_fkey FOREIGN KEY (domain_option_id) + REFERENCES domain_option(domain_option_id) DEFERRABLE; + +ALTER TABLE ONLY domain__domain_option + ADD CONSTRAINT domain_id_fkey FOREIGN KEY (domain_id) + REFERENCES domain(domain_id) DEFERRABLE; + diff --git a/db-migration/database/migrate.sql b/db-migration/database/migrate.sql deleted file mode 100644 index e69de29..0000000