Skip to content

Commit

Permalink
Refactor SQL scripts to update orders schema:
Browse files Browse the repository at this point in the history
As we use orders to represent subscriptions/memberships, delete the memberships SQL scripts, and add appropriate attributes to the quotas and orders tables. Renumber the scripts for flyway migrations.

refs #65
  • Loading branch information
csjx committed Oct 6, 2020
1 parent 24749f0 commit ae015f5
Show file tree
Hide file tree
Showing 17 changed files with 35 additions and 89 deletions.
Original file line number Diff line number Diff line change
@@ -0,0 +1,6 @@
--- Note that this is completed in k8s via the Dockerfile
--- or via a shell script in non-k8s development envs

--- Add a unique constraint to the quotas table for the orderId and quotaType columns
CREATE UNIQUE INDEX quotas_order_id_quota_type_idx
ON quotas USING btree(orderId, quotaType);

This file was deleted.

12 changes: 7 additions & 5 deletions src/main/resources/db/migrations/V1.1__Create_Quotas_Table.sql
Original file line number Diff line number Diff line change
Expand Up @@ -12,13 +12,14 @@ CREATE TABLE IF NOT EXISTS quotas (
hardLimit double precision NOT NULL,
totalUsage double precision,
unit text NOT NULL,
membershipId integer,
subject text
orderId integer,
subject text,
name text
);
ALTER SEQUENCE quotas_id_seq OWNED BY quotas.id;

CREATE INDEX quotas_quotaType_idx ON quotas USING btree(quotaType);
CREATE INDEX quotas_membershipId_idx ON quotas USING btree(membershipId);
CREATE INDEX quotas_orderId_idx ON quotas USING btree(orderId);
CREATE INDEX quotas_subject_idx ON quotas USING btree(subject);

COMMENT ON TABLE quotas IS 'Quotas limiting resources for products per customer. Quotas may be associated with products or customers by their ids.';
Expand All @@ -29,5 +30,6 @@ COMMENT ON COLUMN quotas.softLimit IS 'The soft limit of the resource.';
COMMENT ON COLUMN quotas.hardLimit IS 'The hard limit of the resource.';
COMMENT ON COLUMN quotas.totalUsage IS 'The current observed total usage of the quota.';
COMMENT ON COLUMN quotas.unit IS 'The named unit of the quota.';
COMMENT ON COLUMN quotas.membershipId IS 'The membership id to which the quota is applied.';
COMMENT ON COLUMN quotas.subject IS 'The subject identifier to which the quota is applied.';
COMMENT ON COLUMN quotas.orderId IS 'The membership id to which the quota is applied.';
COMMENT ON COLUMN quotas.subject IS 'The subject identifier to which the quota is applied.';
COMMENT ON COLUMN quotas.name IS 'The quota name, copied from the order name.';
Original file line number Diff line number Diff line change
@@ -1,14 +1,14 @@
-- Insert quotas for portal and storage quotas;

-- 1GB base storage limit
INSERT INTO quotas (object, quotaType, softLimit, hardLimit, totalUsage, unit, membershipId, subject)
INSERT INTO quotas (object, quotaType, softLimit, hardLimit, totalUsage, unit, orderId, subject)
VALUES ('quota', 'storage', 1073741824.0, 1181116006.4, NULL, 'byte', NULL, NULL);

-- 1TB base hosted repository storage limit
INSERT INTO quotas (object, quotaType, softLimit, hardLimit, totalUsage, unit, membershipId, subject)
INSERT INTO quotas (object, quotaType, softLimit, hardLimit, totalUsage, unit, orderId, subject)
VALUES ('quota', 'repository_storage', 1099511627776.0, 1209462790553.6, NULL, 'byte', NULL,
NULL);

-- Single base branded portal limit
INSERT INTO quotas (object, quotaType, softLimit, hardLimit, totalUsage, unit, membershipId, subject)
INSERT INTO quotas (object, quotaType, softLimit, hardLimit, totalUsage, unit, orderId, subject)
VALUES ('quota', 'portal', 1.0, 1.0, NULL, 'portal', NULL, NULL);
Original file line number Diff line number Diff line change
@@ -0,0 +1,7 @@
--- Note that this is completed in k8s via the Dockerfile
--- or via a shell script in non-k8s development envs

--- Add the order id foreign key constraint
ALTER TABLE quotas
ADD CONSTRAINT quotas_order_id_fk
FOREIGN KEY (orderId) REFERENCES orders (id) ON DELETE CASCADE;

This file was deleted.

This file was deleted.

This file was deleted.

Original file line number Diff line number Diff line change
Expand Up @@ -13,15 +13,21 @@ CREATE TABLE IF NOT EXISTS orders (
created timestamp with time zone,
currency text,
customer integer,
subject text,
email text,
items json,
metadata json,
name text,
status text,
statusTransitions json,
updated timestamp with time zone
updated timestamp with time zone,
seriesId text,
startDate timestamp with time zone,
endDate timestamp with time zone
);

CREATE INDEX orders_customer_idx ON orders USING btree(customer);
CREATE INDEX orders_customer_idx ON orders USING btree(subject);
CREATE INDEX orders_email_idx ON orders USING btree(email);
CREATE INDEX orders_status_idx ON orders USING btree(status);

Expand All @@ -34,10 +40,15 @@ COMMENT ON COLUMN orders.charge IS 'The order transaction charge JSON object.';
COMMENT ON COLUMN orders.created IS 'The order creation date.';
COMMENT ON COLUMN orders.currency IS 'The order currency code.';
COMMENT ON COLUMN orders.customer IS 'The order customer identifier.';
COMMENT ON COLUMN orders.subject IS 'The order user or group subject identifier.';
COMMENT ON COLUMN orders.email IS 'The order customer email.';
COMMENT ON COLUMN orders.items IS 'The order items list JSON object.';
COMMENT ON COLUMN orders.metadata IS 'The order metadata JSON object.';
COMMENT ON COLUMN orders.name IS 'The order name set by the customer.';
COMMENT ON COLUMN orders.status IS 'The order status (created, paid, canceled, fulfilled, returned.';
COMMENT ON COLUMN orders.statusTransitions IS 'The order status/date transitions JSON object';
COMMENT ON COLUMN orders.updated IS 'The order update date.';
COMMENT ON COLUMN orders.seriesId IS 'The order series identifier to track renewals.';
COMMENT ON COLUMN orders.startDate IS 'The order services start date.';
COMMENT ON COLUMN orders.endDate IS 'The order services end date.';

This file was deleted.

0 comments on commit ae015f5

Please sign in to comment.