create or replace function sos.register_user(_email text, _password_hash text) returns setof sos.user language plpgsql as $function$ declare _user_uuid uuid; begin insert into sos."user" ( user_email, user_password_hash ) values ( _email, _password_hash ) returning user_uuid into _user_uuid; return query select * from sos."user" where user_uuid = _user_uuid; end; $function$; create or replace function sos.change_password(_user_uuid uuid, _new_hash text) returns setof sos.user language plpgsql as $function$ begin update sos."user" set ( user_password_hash, user_time_password_changed ) = ( _new_hash, now() ) where user_uuid = _user_uuid; return query select * from sos."user" where user_uuid = _user_uuid; end; $function$; create or replace function sos.validate_session(_session_uuid uuid) returns setof sos.v_session language plpgsql as $function$ begin return query select * from sos.v_session where session_uuid = _session_uuid and session_time_logged_out is null and session_time_last_active + session_timeout_length > now(); end; $function$; create or replace function sos.update_session(_session_uuid uuid) returns setof sos.v_session language plpgsql as $function$ begin update sos."session" set session_time_last_active = now() where session_uuid = _session_uuid and session_time_logged_out is null and now() < (select session_time_last_active + session_timeout_length); return query select * from sos.validate_session(_session_uuid); end; $function$; create or replace function sos.login_user_session(_user_uuid uuid, _timeout_length interval, _ip_addr varchar(50), _user_agent varchar(500), _referer varchar(500)) returns setof sos.v_session language plpgsql as $function$ declare _session_uuid uuid; begin insert into sos."session" ( session_user_uuid, session_timeout_length, session_ip_address, session_user_agent, session_referer ) values ( _user_uuid, _timeout_length, _ip_addr, _user_agent, _referer ) returning session_uuid into _session_uuid; return query select * from sos.validate_session(_session_uuid); end; $function$; create or replace function sos.end_session(_session_uuid uuid) returns setof sos.v_session language plpgsql as $function$ begin update sos."session" set session_time_logged_out = now() where session_uuid = _session_uuid and session_time_logged_out is null and now() < (select session_time_last_active + session_timeout_length); return query select * from sos.validate_session(_session_uuid); end; $function$; create or replace function sos.create_item(_name text, _urlslug citext, _description text, _price_cents integer, _published boolean, _hs_num text, _customs_desc text, _origin_country text, _weight integer) returns setof sos.v_item language plpgsql as $function$ declare _item_uuid uuid; begin insert into sos."item" ( item_name, item_urlslug, item_description, item_price_cents, item_published, item_hs_tariff_number, item_customs_description, item_customs_origin_country, item_weight_oz ) values ( _name, _urlslug, _description, _price_cents, _published, _hs_num, _customs_desc, _origin_country, _weight ) returning item_uuid into _item_uuid; return query select * from sos.v_item where item_uuid = _item_uuid; end; $function$; create or replace function sos.update_item(_uuid uuid, _name text, _urlslug citext, _description text, _price_cents integer, _published boolean) returns setof sos.v_item language plpgsql as $function$ begin update sos."item" set ( item_name, item_urlslug, item_description, item_price_cents, item_published ) = ( _name, _urlslug, _description, _price_cents, _published ) where item_uuid = _uuid; return query select * from sos.v_item where item_uuid = _uuid; end; $function$; create or replace function sos.add_image_to_item(_item_uuid uuid, _large_file bytea, _thumb_file bytea, _mime_type varchar, _uploader_uuid uuid) returns setof sos.v_item language plpgsql as $function$ declare _image_uuid uuid; begin insert into sos."image" ( image_item_uuid, image_large_file, image_thumb_file, image_mime_type, image_uploader_uuid ) values ( _item_uuid, _large_file, _thumb_file, _mime_type, _uploader_uuid ) returning image_uuid into _image_uuid; return query select * from sos.v_item where item_uuid = _item_uuid; end; $function$; create or replace function sos.remove_image(_image_uuid uuid) returns setof sos.v_item language plpgsql as $function$ declare _item_uuid uuid; begin select image_item_uuid into _item_uuid from sos."image" where image_uuid = _image_uuid; delete from sos."image" where image_uuid = _image_uuid; return query select * from sos.v_item where item_uuid = _item_uuid; end; $function$; create or replace function sos.set_featured_image(_image_uuid uuid) returns setof sos.v_item language plpgsql as $function$ declare _item_uuid uuid; begin select image_item_uuid into _item_uuid from sos."image" where image_uuid = _image_uuid; -- Un-feature all other images update sos."image" set image_featured = false where image_item_uuid = _item_uuid; update sos."image" set image_featured = true where image_uuid = _image_uuid; return query select * from sos.v_item where item_uuid = _item_uuid; end; $function$; create or replace function sos.get_image_large(_image_uuid uuid) returns table (image_uuid uuid, image_mime_type varchar, image_file bytea) language plpgsql as $function$ begin return query select "image".image_uuid, "image".image_mime_type, "image".image_large_file as image_file from sos."image" where "image".image_uuid = _image_uuid; end; $function$; create or replace function sos.get_image_thumb(_image_uuid uuid) returns table (image_uuid uuid, image_mime_type varchar, image_file bytea) language plpgsql as $function$ begin return query select "image".image_uuid, "image".image_mime_type, "image".image_thumb_file as image_file from sos."image" where "image".image_uuid = _image_uuid; end; $function$; create or replace function sos.create_category(_category_name text, _category_urlslug citext, _category_description text) returns setof sos.v_category language plpgsql as $function$ declare _category_uuid uuid; begin insert into sos."category" ( category_name, category_urlslug, category_description ) values ( _category_name, _category_urlslug, _category_description ) returning category_uuid into _category_uuid; return query select * from sos.v_category where category_uuid = _category_uuid; end; $function$; create or replace function sos.update_category(_category_uuid uuid, _category_name text, _category_urlslug citext, _category_description text) returns setof sos.v_category language plpgsql as $function$ begin update sos."category" set ( category_name, category_urlslug, category_description ) = ( _category_name, _category_urlslug, _category_description ) where category_uuid = _category_uuid; return query select * from sos.v_category where category_uuid = _category_uuid; end; $function$; create or replace function sos.delete_category(_category_uuid uuid) returns setof sos.v_category language plpgsql as $function$ begin -- Remove all items from category delete from sos."category_item" where category_item_category_uuid = _category_uuid; -- Remove all children from category delete from sos."category_category" where category_category_parent_uuid = _category_uuid; -- Remove from all parent categories delete from sos."category_category" where category_category_child_uuid = _category_uuid; -- Remove the category delete from sos."category" where category_uuid = _category_uuid; return query select * from sos.v_category; end; $function$; create or replace function sos.add_item_to_category(_category_uuid uuid, _item_uuid uuid) returns setof sos.v_category language plpgsql as $function$ begin insert into sos."category_item" ( category_item_item_uuid, category_item_category_uuid ) values ( _item_uuid, _category_uuid ); return query select * from sos.v_category where category_uuid = _category_uuid; end; $function$; create or replace function sos.remove_item_from_category(_category_uuid uuid, _item_uuid uuid) returns setof sos.v_category language plpgsql as $function$ begin delete from sos."category_item" where category_item_item_uuid = _item_uuid and category_item_category_uuid = _category_uuid; return query select * from sos.v_category where category_uuid = _category_uuid; end; $function$; create or replace function sos.add_category_to_category(_parent_uuid uuid, _child_uuid uuid) returns setof sos.v_category language plpgsql as $function$ begin insert into sos."category_category" ( category_category_parent_uuid, category_category_child_uuid ) values ( _parent_uuid, _child_uuid ); return query select * from sos.v_category where category_uuid = _parent_uuid; end; $function$; create or replace function sos.remove_category_from_category(_parent_uuid uuid, _child_uuid uuid) returns setof sos.v_category language plpgsql as $function$ begin delete from sos."category_category" where category_category_parent_uuid = _parent_uuid and category_category_child_uuid = _child_uuid; return query select * from sos.v_category where category_uuid = _parent_uuid; end; $function$; create or replace function sos.create_cart(_session_uuid uuid) returns setof sos.v_cart language plpgsql as $function$ declare _cart_uuid uuid; begin insert into sos."cart" default values returning cart_uuid into _cart_uuid; update sos."session" set session_cart = _cart_uuid where session_uuid = _session_uuid and session_time_logged_out is null and now() < (select session_time_last_active + session_timeout_length); return query select * from sos.v_cart where cart_uuid = _cart_uuid; end; $function$; create or replace function sos.add_item_to_cart(_cart_uuid uuid, _item_uuid uuid, _amount integer) returns setof sos.v_cart language plpgsql as $function$ declare _row_count integer; begin -- Invalidate transactions that use this cart perform sos.cancel_transactions_for_cart(_cart_uuid); -- Check if we already have a row for this combination select count(*) into _row_count from sos.cart_item where cart_item_cart_uuid = _cart_uuid and cart_item_item_uuid = _item_uuid; -- If we found a row, increment otherwise insert if _row_count > 0 then update sos.cart_item set cart_item_count = cart_item_count + _amount where cart_item_cart_uuid = _cart_uuid and cart_item_item_uuid = _item_uuid; else insert into sos.cart_item ( cart_item_cart_uuid, cart_item_item_uuid, cart_item_count ) values ( _cart_uuid, _item_uuid, _amount ); end if; -- Return cart return query select * from sos.v_cart where cart_uuid = _cart_uuid; end; $function$; create or replace function sos.remove_item_from_cart(_cart_uuid uuid, _item_uuid uuid, _amount integer) returns setof sos.v_cart language plpgsql as $function$ declare _row_count integer; _current_amount integer; begin -- Invalidate transactions that use this cart perform sos.cancel_transactions_for_cart(_cart_uuid); -- Check if we already have a row for this combination select count(*), cart_item_count into _row_count, _current_amount from sos.cart_item where cart_item_cart_uuid = _cart_uuid and cart_item_item_uuid = _item_uuid group by cart_item_uuid, cart_item_count; -- If we do not have a row, just exit if _row_count < 1 then return query select * from sos.v_cart where cart_uuid = _cart_uuid; end if; -- If we do not have enough to decrement, delete row if _current_amount <= _amount then delete from sos.cart_item where cart_item_cart_uuid = _cart_uuid and cart_item_item_uuid = _item_uuid; -- Else, decrement row else update sos.cart_item set cart_item_count = cart_item_count - _amount where cart_item_cart_uuid = _cart_uuid and cart_item_item_uuid = _item_uuid; end if; -- Return cart return query select * from sos.v_cart where cart_uuid = _cart_uuid; end; $function$; create or replace function sos.remove_item_from_cart(_cart_uuid uuid, _item_uuid uuid) returns setof sos.v_cart language plpgsql as $function$ declare _row_count integer; begin -- Invalidate transactions that use this cart perform sos.cancel_transactions_for_cart(_cart_uuid); -- Check if we already have a row for this combination select count(*) into _row_count from sos.cart_item where cart_item_cart_uuid = _cart_uuid and cart_item_item_uuid = _item_uuid group by cart_item_uuid, cart_item_count; -- If we do not have a row, just exit if _row_count < 1 then return query select * from sos.v_cart where cart_uuid = _cart_uuid; end if; -- If we have a row, then delete it delete from sos.cart_item where cart_item_cart_uuid = _cart_uuid and cart_item_item_uuid = _item_uuid; -- Return cart return query select * from sos.v_cart where cart_uuid = _cart_uuid; end; $function$; create or replace function sos.publish_item(_item_uuid uuid) returns setof sos.v_item language plpgsql as $function$ begin update sos."item" set item_published = true where item_uuid = _item_uuid; return query select * from sos.v_item where item_uuid = _item_uuid; end; $function$; create or replace function sos.unpublish_item(_item_uuid uuid) returns setof sos.v_item language plpgsql as $function$ begin update sos."item" set item_published = false where item_uuid = _item_uuid; return query select * from sos.v_item where item_uuid = _item_uuid; end; $function$; create or replace function sos.create_order(_cart_uuid uuid, _session_uuid uuid) returns setof sos.v_order language plpgsql as $function$ declare _completed_transactions integer; _order_uuid uuid; _existing_transaction uuid; _cart_price integer; begin -- Check for completed transactions select count(*) into _completed_transactions from sos."transaction" where transaction_cart_uuid = _cart_uuid and transaction_payment_state = 'completed'; if _completed_transactions > 0 then raise 'Cart has already been purchased'; end if; -- Check for existing transaction for this cart? select transaction_order_uuid, transaction_uuid into _order_uuid, _existing_transaction from sos."transaction" where transaction_cart_uuid = _cart_uuid and transaction_payment_state = 'started'; -- Update existing transaction to current session if _existing_transaction is not null then update sos."transaction" set transaction_session_uuid = _session_uuid where transaction_uuid = _existing_transaction; end if; -- If no existing order, create an order and a transaction if _order_uuid is null then -- Create order insert into sos."order" default values returning order_uuid into _order_uuid; -- Get cart cost select cart_price into _cart_price from sos.v_cart_price where cart_uuid = _cart_uuid; -- Create transaction insert into sos."transaction" ( transaction_order_uuid, transaction_cart_uuid, transaction_item_total_price, transaction_session_uuid ) values ( _order_uuid, _cart_uuid, _cart_price, _session_uuid ); end if; return query select * from sos.v_order where order_uuid = _order_uuid; end; $function$; create or replace function sos.cancel_transactions_for_cart(_cart_uuid uuid) returns void language plpgsql as $function$ declare _completed_transactions integer; begin select count(*) into _completed_transactions from sos."transaction" where transaction_cart_uuid = _cart_uuid and transaction_payment_state = 'completed'; if _completed_transactions > 0 then raise 'Cart has already been purchased'; end if; update sos."transaction" set ( transaction_completion_time, transaction_payment_state )= ( now(), 'cancelled' ) where transaction_cart_uuid = _cart_uuid and transaction_payment_state = 'started'; end; $function$; create or replace function sos.find_order_for_cart(_cart_uuid uuid) returns setof sos.v_order language plpgsql as $function$ declare _order_uuid uuid; begin select transaction_order_uuid into _order_uuid from sos."transaction" where transaction_cart_uuid = _cart_uuid and transaction_payment_state = 'started'; return query select * from sos.v_order where order_uuid = _order_uuid; end; $function$; create or replace function sos.find_orders_for_session(_session_uuid uuid) returns setof sos.v_order language plpgsql as $function$ begin return query select "order".* from sos."transaction" left join sos.v_order "order" on "order".order_uuid = "transaction".transaction_order_uuid where "transaction".transaction_session_uuid = _session_uuid and ( "transaction".transaction_payment_state = 'started' or "transaction".transaction_payment_state = 'completed' ); end; $function$; create or replace function sos.find_orders_for_user(_user_uuid uuid) returns setof sos.v_order language plpgsql as $function$ begin return query select * from sos.v_order where order_user_uuid = _user_uuid and ( transaction_payment_state = 'started' or transaction_payment_state = 'completed' ); end; $function$; create or replace function sos.set_user_on_order(_order_uuid uuid, _user_uuid uuid) returns setof sos.v_order language plpgsql as $function$ begin -- Update order update sos."order" set order_user_uuid = _user_uuid where order_uuid = _order_uuid; return query select * from sos.v_order where order_uuid = _order_uuid; end; $function$; create or replace function sos.create_address(_name text, _company text, _street1 text, _street2 text, _city text, _state text, _zip text, _country text, _phone text, _easypost_id text, _verified boolean) returns setof sos."address" language plpgsql as $function$ declare _address_uuid uuid; begin insert into sos."address" ( address_name, address_company, address_street1, address_street2, address_city, address_state, address_zip, address_country, address_phone, address_easypost_id, address_verified ) values ( _name, _company, _street1, _street2, _city, _state, _zip, _country, _phone, _easypost_id, _verified ) returning address_uuid into _address_uuid; return query select * from sos."address" where address_uuid = _address_uuid; end; $function$; create or replace function sos.add_address_to_order(_transaction_uuid uuid, _address_uuid uuid, _shipping_price integer) returns setof sos.v_order language plpgsql as $function$ declare _purchased_transactions integer; _order_uuid uuid; begin -- Get the transaction's order select transaction_order_uuid into _order_uuid from sos."transaction" where transaction_uuid = _transaction_uuid; if _order_uuid is null then raise 'Transaction has no order'; end if; -- Check that the order does not already have purchased transactions. This function doesn't handle that case -- (because if an order changes address we need to charge shipping difference for other transactions) select count(*) into _purchased_transactions from sos.v_order where order_uuid = _order_uuid and transaction_payment_state = 'completed'; if _purchased_transactions > 0 then raise 'Order already has an address'; end if; -- Update order update sos."order" set order_address_uuid = _address_uuid where order_uuid = _order_uuid; -- Update transaction with price update sos."transaction" set transaction_shipping_price = _shipping_price where transaction_uuid = _transaction_uuid; return query select * from sos.v_order where order_uuid = _order_uuid; end; $function$; create or replace function sos.create_coupon(_code varchar(50), _valid_until timestamptz, _free_shipping boolean, _number_allowed_uses integer, _flat_discount_cents integer, _percent_discount integer, _per_sock_discount_cents integer, _number_of_socks_free integer) returns setof sos.coupon language plpgsql as $function$ declare _coupon_uuid uuid; begin insert into sos."coupon" ( coupon_code, coupon_valid_until, coupon_free_shipping, coupon_number_allowed_uses, coupon_flat_discount_cents, coupon_percent_discount, coupon_per_sock_discount_cents, coupon_number_of_socks_free ) values ( _code, _valid_until, _free_shipping, _number_allowed_uses, _flat_discount_cents, _percent_discount, _per_sock_discount_cents, _number_of_socks_free ) returning coupon_uuid into _coupon_uuid; return query select * from sos.coupon where coupon_uuid = _coupon_uuid; end; $function$; create or replace function sos.add_coupon_to_transaction(_transaction_uuid uuid, _coupon_uuid uuid, _item_discount integer) returns setof sos.v_order language plpgsql as $function$ declare _order_uuid uuid; _purchased_transactions integer; begin -- Get the transaction's order select transaction_order_uuid into _order_uuid from sos."transaction" where transaction_uuid = _transaction_uuid; if _order_uuid is null then raise 'Transaction has no order'; end if; -- TODO: Check for other uses of this coupon. Compare to the number_allowed_uses. -- Check that this transaction is "started" select count(*) into _purchased_transactions from sos.v_order where transaction_uuid = _transaction_uuid and transaction_payment_state != 'started'; if _purchased_transactions > 0 then raise 'Order has been cancelled or purchased'; end if; -- Update transaction update sos."transaction" set ( transaction_coupon_uuid, transaction_coupon_effective_discount ) = ( _coupon_uuid, _item_discount ) where transaction_uuid = _transaction_uuid; return query select * from sos.v_order where order_uuid = _order_uuid; end; $function$; create or replace function sos.find_order_for_transaction(_transaction_uuid uuid) returns setof sos.v_order language plpgsql as $function$ begin return query select v_order.* from sos."transaction" left join sos.v_order on "transaction".transaction_order_uuid = v_order.order_uuid where "transaction".transaction_uuid = _transaction_uuid; end; $function$; create or replace function sos.add_stripe_payment_to_transaction(_transaction_uuid uuid, _payment_value_cents integer, _stripe_intent_id text, _stripe_receipt_email citext, _stripe_receipt_number text) returns setof sos.v_order language plpgsql as $function$ declare _payment_uuid uuid; _is_paid integer; _order_uuid uuid; begin -- Get the transaction's order select transaction_order_uuid into _order_uuid from sos."transaction" where transaction_uuid = _transaction_uuid; if _order_uuid is null then raise 'Transaction has no order'; end if; insert into sos."payment" ( payment_type, payment_value_cents, payment_transaction_uuid ) values ( 'stripe', _payment_value_cents, _transaction_uuid ) returning payment_uuid into _payment_uuid; insert into sos."payment_stripe" ( payment_uuid, payment_type, stripe_payment_intent_id, stripe_receipt_email, stripe_receipt_number ) values ( _payment_uuid, 'stripe', _stripe_intent_id, _stripe_receipt_email, _stripe_receipt_number ); select count(*) into _is_paid from sos.v_order where transaction_uuid = _transaction_uuid and transaction_computed_price <= transaction_amount_paid_cents; if _is_paid > 0 then update sos."transaction" set ( transaction_payment_state, transaction_completion_time ) = ( 'completed', now() ) where transaction_uuid = _transaction_uuid; end if; return query select * from sos.v_order where order_uuid = _order_uuid; end; $function$; create or replace function sos.add_admin_payment_to_transaction(_transaction_uuid uuid, _payment_value_cents integer, _recipient_email citext, _reason text, _granter uuid) returns setof sos.v_order language plpgsql as $function$ declare _payment_uuid uuid; _is_paid integer; _order_uuid uuid; begin -- Get the transaction's order select transaction_order_uuid into _order_uuid from sos."transaction" where transaction_uuid = _transaction_uuid; if _order_uuid is null then raise 'Transaction has no order'; end if; insert into sos."payment" ( payment_type, payment_value_cents, payment_transaction_uuid ) values ( 'admin_granted', _payment_value_cents, _transaction_uuid ) returning payment_uuid into _payment_uuid; insert into sos."payment_admin_grant" ( payment_uuid, payment_type, payment_admin_granted_by, payment_admin_recipient_email, payment_admin_reason ) values ( _payment_uuid, 'admin_granted', _granter, _recipient_email, _reason ); select count(*) into _is_paid from sos.v_order where transaction_uuid = _transaction_uuid and transaction_computed_price <= transaction_amount_paid_cents; if _is_paid > 0 then update sos."transaction" set ( transaction_payment_state, transaction_completion_time ) = ( 'completed', now() ) where transaction_uuid = _transaction_uuid; end if; return query select * from sos.v_order where order_uuid = _order_uuid; end; $function$; create or replace function sos.attach_cart(_session_uuid uuid, _cart_uuid uuid) returns setof sos.v_session language plpgsql as $function$ begin update sos."session" set session_cart = _cart_uuid where session_uuid = _session_uuid and session_time_logged_out is null and now() < (select session_time_last_active + session_timeout_length); return query select * from sos.v_session where session_uuid = _session_uuid; end; $function$; create or replace function sos.clear_cart(_session_uuid uuid) returns setof sos.v_session language plpgsql as $function$ begin update sos."session" set session_cart = null where session_uuid = _session_uuid and session_time_logged_out is null and now() < (select session_time_last_active + session_timeout_length); return query select * from sos.v_session where session_uuid = _session_uuid; end; $function$; create or replace function sos.deduct_stock_for_purchase(_transaction_uuid uuid) returns setof sos.v_item language plpgsql as $function$ declare _item_uuids uuid[]; _cart_uuid uuid; _item_uuid uuid; _cart_item_count integer; _available_item_count integer; _item_availability_date timestamptz; _stockchange_uuid uuid; begin -- Get cart uuid (and check completed) select transaction_cart_uuid into _cart_uuid from sos."transaction" where transaction_uuid = _transaction_uuid and transaction_payment_state = 'completed'; -- Double check we got the cart -- (Will be null if transaction is not complete) if _cart_uuid is null then raise 'Transaction not complete'; end if; -- Get item array _item_uuids := ARRAY( select cart_item_item_uuid from sos."cart_item" where cart_item_cart_uuid = _cart_uuid ); -- Make stock-change record for each item foreach _item_uuid in array _item_uuids loop -- Get cart and item info select cart_item_count into _cart_item_count from sos."cart_item" where cart_item_cart_uuid = _cart_uuid and cart_item_item_uuid = _item_uuid; select item_number_in_stock, item_preorder_availability_date into _available_item_count, _item_availability_date from sos.v_item where item_uuid = _item_uuid; -- Pre-order stockchange if _cart_item_count > _available_item_count and _item_availability_date is not null then insert into sos."item_stockchange" ( stockchange_type, stockchange_item_uuid, stockchange_change, stockchange_direction ) values ( 'preorder', _item_uuid, _cart_item_count, 'subtracted' ) returning stockchange_uuid into _stockchange_uuid; insert into sos."item_stockchange_preorder" ( stockchange_uuid, stockchange_type, stockchange_transaction_uuid, stockchange_preorder_estimated_fulfill_date ) values ( _stockchange_uuid, 'preorder', _transaction_uuid, _item_availability_date ); else -- Non-preorder stockchange insert into sos."item_stockchange" ( stockchange_type, stockchange_item_uuid, stockchange_change, stockchange_direction ) values ( 'purchase', _item_uuid, _cart_item_count, 'subtracted' ) returning stockchange_uuid into _stockchange_uuid; insert into sos."item_stockchange_purchase" ( stockchange_uuid, stockchange_type, stockchange_transaction_uuid ) values ( _stockchange_uuid, 'purchase', _transaction_uuid ); end if; end loop; return query select * from sos.v_item where item_uuid = any(_item_uuids); end; $function$; create or replace function sos.add_tax_to_transaction(_transaction_uuid uuid, _tax_price integer) returns setof sos.v_order language plpgsql as $function$ begin -- Update transaction update sos."transaction" set transaction_tax_price = _tax_price where transaction_uuid = _transaction_uuid; return query select * from sos.find_order_for_transaction(_transaction_uuid); end; $function$; create or replace function sos.create_shipment(_shipment_description text, _item_uuids uuid[], _counts integer[]) returns setof sos.v_shipment language plpgsql as $function$ declare _shipment_uuid uuid; _stockchange_uuid uuid; begin -- Check that the arrays are the same length if array_length(_item_uuids, 1) != array_length(_counts, 1) then raise 'Arrays are not of the same length'; end if; -- Create shipment insert into sos."shipment" ( shipment_description ) values ( _shipment_description ) returning shipment_uuid into _shipment_uuid; -- Create all the item stockchanges for i in array_lower(_item_uuids, 1) .. array_upper(_item_uuids, 1) loop insert into sos."item_stockchange" ( stockchange_type, stockchange_item_uuid, stockchange_change, stockchange_direction ) values ( 'shipment', _item_uuids[i], _counts[i], 'added' ) returning stockchange_uuid into _stockchange_uuid; insert into sos."item_stockchange_shipment" ( stockchange_uuid, stockchange_type, stockchange_shipment_uuid ) values ( _stockchange_uuid, 'shipment', _shipment_uuid ); perform sos.mark_preorders_shippable(_item_uuids[i], _counts[i]); end loop; return query select * from sos.v_shipment where shipment_uuid = _shipment_uuid; end; $function$; create or replace function sos.mark_preorders_shippable(_item_uuid uuid, _count integer) returns void language plpgsql as $function$ declare _preorder_uuids uuid[]; _num_marked integer := 0; _current_num integer; _current_direction sos.stock_change_dir_enum; _remaining_preorders integer; begin -- Get unfulfilled pre-order stockchanges for this item, ordered by transaction completion time select array_agg(item_stockchange.stockchange_uuid order by transaction_completion_time) into _preorder_uuids from sos.item_stockchange left join sos.item_stockchange_preorder on item_stockchange.stockchange_uuid = item_stockchange_preorder.stockchange_uuid left join sos.transaction on stockchange_transaction_uuid = transaction_uuid where stockchange_item_uuid = _item_uuid and item_stockchange.stockchange_type = 'preorder' and stockchange_preorder_ready_to_ship = false group by stockchange_item_uuid; -- For all stockchanges if _preorder_uuids is not null then for i in array_lower(_preorder_uuids, 1) .. array_upper(_preorder_uuids, 1) loop select stockchange_direction, stockchange_change into _current_direction, _current_num from sos.item_stockchange where stockchange_uuid = _preorder_uuids[i]; -- Sanity check: Only fulfill ones that deducted stock if _current_direction != 'subtracted' then continue; end if; -- Don't fulfill more than we have if _num_marked + _current_num > _count then exit; end if; update sos.item_stockchange_preorder set stockchange_preorder_ready_to_ship = true where stockchange_uuid = _preorder_uuids[i]; _num_marked := _num_marked + _current_num; end loop; end if; -- Count remaining pre-orders select count(item_stockchange.stockchange_uuid) into _remaining_preorders from sos.item_stockchange left join sos.item_stockchange_preorder on item_stockchange.stockchange_uuid = item_stockchange_preorder.stockchange_uuid where stockchange_item_uuid = _item_uuid and item_stockchange.stockchange_type = 'preorder' and stockchange_preorder_ready_to_ship = false group by stockchange_item_uuid; -- If we no longer have pre-orders clear item pre-order records if _remaining_preorders < 1 then update sos.item set ( item_preorder_availability_date, item_preorder_maximum ) = ( null, null ) where item_uuid = _item_uuid; end if; end; $function$; create or replace function sos.set_delivery_tracking(_order_uuid uuid, _tracking_number text, _date_shipped timestamptz, _price_cents integer) returns setof sos.v_order language plpgsql as $function$ declare _delivery_uuid uuid; begin -- Ensure order has no delivery select order_delivery_uuid into _delivery_uuid from sos."order" where order_uuid = _order_uuid; if _delivery_uuid is not null then raise 'Order already has a delivery record'; end if; -- Create delivery insert into sos."delivery" ( delivery_type ) values ( 'hand_shipped' ) returning delivery_uuid into _delivery_uuid; -- Default date if _date_shipped is null then _date_shipped := now(); end if; -- Create delivery subtype record insert into sos."delivery_hand_shipped" ( delivery_uuid, delivery_type, delivery_price_cents, delivery_tracking_number, delivery_date_shipped ) values ( _delivery_uuid, 'hand_shipped', _price_cents, _tracking_number, _date_shipped ); -- Update order update sos."order" set order_delivery_uuid = _delivery_uuid where order_uuid = _order_uuid; return query select * from sos.v_order where order_uuid = _order_uuid; end; $function$; create or replace function sos.set_delivery_by_hand(_order_uuid uuid, _description text, _date_delivered timestamptz) returns setof sos.v_order language plpgsql as $function$ declare _delivery_uuid uuid; begin -- Ensure order has no delivery select order_delivery_uuid into _delivery_uuid from sos."order" where order_uuid = _order_uuid; if _delivery_uuid is not null then raise 'Order already has a delivery record'; end if; -- Create delivery insert into sos."delivery" ( delivery_type ) values ( 'hand_delivered' ) returning delivery_uuid into _delivery_uuid; -- Default date if _date_delivered is null then _date_delivered := now(); end if; -- Create delivery subtype record insert into sos."delivery_hand_delivered" ( delivery_uuid, delivery_type, delivery_description, delivery_date_delivered ) values ( _delivery_uuid, 'hand_delivered', _description, _date_delivered ); -- Update order update sos."order" set order_delivery_uuid = _delivery_uuid where order_uuid = _order_uuid; return query select * from sos.v_order where order_uuid = _order_uuid; end; $function$; create or replace function sos.set_delivery_easypost(_order_uuid uuid, _easypost_id text, _tracking_number text, _price_cents integer) returns setof sos.v_order language plpgsql as $function$ declare _delivery_uuid uuid; begin -- Ensure order has no delivery select order_delivery_uuid into _delivery_uuid from sos."order" where order_uuid = _order_uuid; if _delivery_uuid is not null then raise 'Order already has a delivery record'; end if; -- Create delivery insert into sos."delivery" ( delivery_type ) values ( 'easypost' ) returning delivery_uuid into _delivery_uuid; -- Create delivery subtype record insert into sos."delivery_easypost" ( delivery_uuid, delivery_type, delivery_price_cents, delivery_tracking_number, delivery_date_shipped, delivery_easypost_id ) values ( _delivery_uuid, 'easypost', _price_cents, _tracking_number, now(), _easypost_id ); -- Update order update sos."order" set order_delivery_uuid = _delivery_uuid where order_uuid = _order_uuid; return query select * from sos.v_order where order_uuid = _order_uuid; end; $function$; create or replace function sos.get_open_email_links_for_user(_user_uuid uuid) returns setof sos."email_link" language plpgsql as $function$ begin return query select * from sos."email_link" where email_link_user_uuid = _user_uuid and email_link_time_used is null and email_link_time_created + email_link_timeout_length > now(); end; $function$; create or replace function sos.create_login_link(_user_uuid uuid, _timeout_length interval, _link_hash text, _type sos.email_link_type_enum) returns setof sos."email_link" language plpgsql as $function$ declare _link_uuid uuid; begin insert into sos."email_link" ( email_link_user_uuid, email_link_timeout_length, email_link_login_hash, email_link_type ) values ( _user_uuid, _timeout_length, _link_hash, _type ) returning email_link_uuid into _link_uuid; return query select * from sos."email_link" where email_link_uuid = _link_uuid; end; $function$; create or replace function sos.set_link_used(_link_uuid uuid) returns setof sos."email_link" language plpgsql as $function$ begin update sos."email_link" set email_link_time_used = now() where email_link_uuid = _link_uuid; return query select * from sos."email_link" where email_link_uuid = _link_uuid; end; $function$; create or replace function sos.set_user_email_verified(_user_uuid uuid) returns setof sos."user" language plpgsql as $function$ begin update sos."user" set ( user_email_confirmed, user_time_email_confirmed ) = ( true, now() ) where user_uuid = _user_uuid; return query select * from sos."user" where user_uuid = _user_uuid; end; $function$; create or replace function sos.set_user_admin(_user_uuid uuid, _is_admin boolean) returns setof sos.v_user language plpgsql as $function$ begin update sos."user" set user_is_admin = _is_admin where user_uuid = _user_uuid; return query select * from sos.v_user where user_uuid = _user_uuid; end; $function$; create or replace function sos.set_shipping_source(_address_uuid uuid, _user_uuid uuid) returns setof sos.v_config language plpgsql as $function$ declare _tax_percent numeric(8,6); begin select config_default_tax_percent into _tax_percent from sos.v_config; insert into sos.config ( config_default_tax_percent, config_shipping_from, config_updated_by ) values ( _tax_percent, _address_uuid, _user_uuid ); return query select * from sos.v_config; end; $function$; create or replace function sos.get_number_of_preorder_reservations(_item_uuid uuid) returns integer language plpgsql as $function$ begin return ( select count(*) from sos.item_stockchange_preorder left join sos.item_stockchange on item_stockchange.stockchange_uuid = item_stockchange_preorder.stockchange_uuid where stockchange_preorder_ready_to_ship = false and stockchange_item_uuid = _item_uuid ); end; $function$; create or replace function sos.set_preorder(_item_uuid uuid, _estimated_delivery timestamptz, _max_preorders integer) returns setof sos.v_item language plpgsql as $function$ declare _num_reserved integer := sos.get_number_of_preorder_reservations(_item_uuid); begin if _num_reserved > _max_preorders then raise 'Cannot lower preorder limit past the number of reservations'; end if; update sos.item set ( item_preorder_availability_date, item_preorder_maximum ) = ( _estimated_delivery, _max_preorders ) where item_uuid = _item_uuid; return query select * from sos.v_item where item_uuid = _item_uuid; end; $function$;