You cannot select more than 25 topics Topics must start with a letter or number, can include dashes ('-') and can be up to 35 characters long.
Verto-Version-Tracking/supabase/migrations/20251222070609_create_trans...

141 lines
4.7 KiB
MySQL

/*
# Transaction and Charge Code Management Tables
1. New Tables
- `transaction_events_master`
- `pet_eventcode` (text, primary key) - Unique event code identifier
- `pet_eventdesc` (text) - Event description
- `system_generated` (boolean) - Flag indicating if system generated
- `created_at` (timestamptz) - Creation timestamp
- `updated_at` (timestamptz) - Last update timestamp
- `transaction_codes`
- `ptr_trancode` (text, primary key) - Unique transaction code identifier
- `pet_eventcode` (text, foreign key) - References transaction_events_master
- `ptr_trandesc` (text) - Transaction description
- `system_generated` (boolean) - Flag indicating if system generated
- `created_at` (timestamptz) - Creation timestamp
- `updated_at` (timestamptz) - Last update timestamp
- `charge_codes`
- `pch_chrgcode` (text, primary key) - Unique charge code identifier
- `pch_chrgdesc` (text) - Charge description
- `pch_chrgshort` (text) - Short charge description
- `pel_elmtcode` (text) - Element code
- `ptr_trancode` (text, foreign key) - References transaction_codes
- `pch_chrgprofit` (numeric) - Charge profit amount
- `soc_charges` (text) - SOC charges information
- `created_at` (timestamptz) - Creation timestamp
- `updated_at` (timestamptz) - Last update timestamp
2. Security
- Enable RLS on all tables
- Add policies for authenticated users to manage their organization's codes
*/
-- Create transaction_events_master table
CREATE TABLE IF NOT EXISTS transaction_events_master (
pet_eventcode text PRIMARY KEY,
pet_eventdesc text NOT NULL,
system_generated boolean DEFAULT false,
created_at timestamptz DEFAULT now(),
updated_at timestamptz DEFAULT now()
);
-- Create transaction_codes table
CREATE TABLE IF NOT EXISTS transaction_codes (
ptr_trancode text PRIMARY KEY,
pet_eventcode text REFERENCES transaction_events_master(pet_eventcode) ON DELETE SET NULL,
ptr_trandesc text NOT NULL,
system_generated boolean DEFAULT false,
created_at timestamptz DEFAULT now(),
updated_at timestamptz DEFAULT now()
);
-- Create charge_codes table
CREATE TABLE IF NOT EXISTS charge_codes (
pch_chrgcode text PRIMARY KEY,
pch_chrgdesc text NOT NULL,
pch_chrgshort text,
pel_elmtcode text,
ptr_trancode text REFERENCES transaction_codes(ptr_trancode) ON DELETE SET NULL,
pch_chrgprofit numeric(10, 2) DEFAULT 0,
soc_charges text,
created_at timestamptz DEFAULT now(),
updated_at timestamptz DEFAULT now()
);
-- Enable RLS
ALTER TABLE transaction_events_master ENABLE ROW LEVEL SECURITY;
ALTER TABLE transaction_codes ENABLE ROW LEVEL SECURITY;
ALTER TABLE charge_codes ENABLE ROW LEVEL SECURITY;
-- Create policies for transaction_events_master
CREATE POLICY "Authenticated users can view transaction events"
ON transaction_events_master FOR SELECT
TO authenticated
USING (true);
CREATE POLICY "Authenticated users can insert transaction events"
ON transaction_events_master FOR INSERT
TO authenticated
WITH CHECK (true);
CREATE POLICY "Authenticated users can update transaction events"
ON transaction_events_master FOR UPDATE
TO authenticated
USING (true)
WITH CHECK (true);
CREATE POLICY "Authenticated users can delete transaction events"
ON transaction_events_master FOR DELETE
TO authenticated
USING (true);
-- Create policies for transaction_codes
CREATE POLICY "Authenticated users can view transaction codes"
ON transaction_codes FOR SELECT
TO authenticated
USING (true);
CREATE POLICY "Authenticated users can insert transaction codes"
ON transaction_codes FOR INSERT
TO authenticated
WITH CHECK (true);
CREATE POLICY "Authenticated users can update transaction codes"
ON transaction_codes FOR UPDATE
TO authenticated
USING (true)
WITH CHECK (true);
CREATE POLICY "Authenticated users can delete transaction codes"
ON transaction_codes FOR DELETE
TO authenticated
USING (true);
-- Create policies for charge_codes
CREATE POLICY "Authenticated users can view charge codes"
ON charge_codes FOR SELECT
TO authenticated
USING (true);
CREATE POLICY "Authenticated users can insert charge codes"
ON charge_codes FOR INSERT
TO authenticated
WITH CHECK (true);
CREATE POLICY "Authenticated users can update charge codes"
ON charge_codes FOR UPDATE
TO authenticated
USING (true)
WITH CHECK (true);
CREATE POLICY "Authenticated users can delete charge codes"
ON charge_codes FOR DELETE
TO authenticated
USING (true);
-- Create indexes for foreign keys
CREATE INDEX IF NOT EXISTS idx_transaction_codes_pet_eventcode ON transaction_codes(pet_eventcode);
CREATE INDEX IF NOT EXISTS idx_charge_codes_ptr_trancode ON charge_codes(ptr_trancode);