diff --git a/Makefile.in b/Makefile.in index 36bf5e32..f5b6d398 100644 --- a/Makefile.in +++ b/Makefile.in @@ -12,6 +12,7 @@ move_large_tuples \ non_sorted_off_compact \ update_compare_indexes \ pgtde_is_encrypted \ +test_issue_153_fix \ multi_insert \ trigger_on_view \ insert_update_delete \ diff --git a/expected/test_issue_153_fix.out b/expected/test_issue_153_fix.out new file mode 100644 index 00000000..8a5150e8 --- /dev/null +++ b/expected/test_issue_153_fix.out @@ -0,0 +1,584 @@ +CREATE EXTENSION pg_tde; +SET datestyle TO 'iso, dmy'; +SELECT * FROM pg_tde_master_key_info(); +ERROR: Master key does not exists for the database +HINT: Use set_master_key interface to set the master key +SELECT pg_tde_add_key_provider_file('file-ring','/tmp/pg_tde_test_keyring.per'); + pg_tde_add_key_provider_file +------------------------------ + 1 +(1 row) + +SELECT pg_tde_set_master_key('test-db-master-key','file-ring'); + pg_tde_set_master_key +----------------------- + t +(1 row) + +-- +-- Script that creates the 'sample' tde encrypted tables, views +-- functions, triggers, etc. +-- +-- Start new transaction - commit all or nothing +-- +BEGIN; +-- +-- Create and load tables used in the documentation examples. +-- +-- Create the 'dept' table +-- +CREATE TABLE dept ( + deptno NUMERIC(2) NOT NULL CONSTRAINT dept_pk PRIMARY KEY, + dname VARCHAR(14) CONSTRAINT dept_dname_uq UNIQUE, + loc VARCHAR(13) +)using pg_tde; +-- +-- Create the 'emp' table +-- +CREATE TABLE emp ( + empno NUMERIC(4) NOT NULL CONSTRAINT emp_pk PRIMARY KEY, + ename VARCHAR(10), + job VARCHAR(9), + mgr NUMERIC(4), + hiredate DATE, + sal NUMERIC(7,2) CONSTRAINT emp_sal_ck CHECK (sal > 0), + comm NUMERIC(7,2), + deptno NUMERIC(2) CONSTRAINT emp_ref_dept_fk + REFERENCES dept(deptno) +)using pg_tde; +-- +-- Create the 'jobhist' table +-- +CREATE TABLE jobhist ( + empno NUMERIC(4) NOT NULL, + startdate TIMESTAMP(0) NOT NULL, + enddate TIMESTAMP(0), + job VARCHAR(9), + sal NUMERIC(7,2), + comm NUMERIC(7,2), + deptno NUMERIC(2), + chgdesc VARCHAR(80), + CONSTRAINT jobhist_pk PRIMARY KEY (empno, startdate), + CONSTRAINT jobhist_ref_emp_fk FOREIGN KEY (empno) + REFERENCES emp(empno) ON DELETE CASCADE, + CONSTRAINT jobhist_ref_dept_fk FOREIGN KEY (deptno) + REFERENCES dept (deptno) ON DELETE SET NULL, + CONSTRAINT jobhist_date_chk CHECK (startdate <= enddate) +)using pg_tde; +-- +-- Create the 'salesemp' view +-- +CREATE OR REPLACE VIEW salesemp AS + SELECT empno, ename, hiredate, sal, comm FROM emp WHERE job = 'SALESMAN'; +-- +-- Sequence to generate values for function 'new_empno'. +-- +CREATE SEQUENCE next_empno START WITH 8000 INCREMENT BY 1; +-- +-- Issue PUBLIC grants +-- +GRANT ALL ON emp TO PUBLIC; +GRANT ALL ON dept TO PUBLIC; +GRANT ALL ON jobhist TO PUBLIC; +GRANT ALL ON salesemp TO PUBLIC; +GRANT ALL ON next_empno TO PUBLIC; +-- +-- Load the 'dept' table +-- +INSERT INTO dept VALUES (10,'ACCOUNTING','NEW YORK'); +INSERT INTO dept VALUES (20,'RESEARCH','DALLAS'); +INSERT INTO dept VALUES (30,'SALES','CHICAGO'); +INSERT INTO dept VALUES (40,'OPERATIONS','BOSTON'); +-- +-- Load the 'emp' table +-- +INSERT INTO emp VALUES (7369,'SMITH','CLERK',7902,'17-DEC-80',800,NULL,20); +INSERT INTO emp VALUES (7499,'ALLEN','SALESMAN',7698,'20-FEB-81',1600,300,30); +INSERT INTO emp VALUES (7521,'WARD','SALESMAN',7698,'22-FEB-81',1250,500,30); +INSERT INTO emp VALUES (7566,'JONES','MANAGER',7839,'02-APR-81',2975,NULL,20); +INSERT INTO emp VALUES (7654,'MARTIN','SALESMAN',7698,'28-SEP-81',1250,1400,30); +INSERT INTO emp VALUES (7698,'BLAKE','MANAGER',7839,'01-MAY-81',2850,NULL,30); +INSERT INTO emp VALUES (7782,'CLARK','MANAGER',7839,'09-JUN-81',2450,NULL,10); +INSERT INTO emp VALUES (7788,'SCOTT','ANALYST',7566,'19-APR-87',3000,NULL,20); +INSERT INTO emp VALUES (7839,'KING','PRESIDENT',NULL,'17-NOV-81',5000,NULL,10); +INSERT INTO emp VALUES (7844,'TURNER','SALESMAN',7698,'08-SEP-81',1500,0,30); +INSERT INTO emp VALUES (7876,'ADAMS','CLERK',7788,'23-MAY-87',1100,NULL,20); +INSERT INTO emp VALUES (7900,'JAMES','CLERK',7698,'03-DEC-81',950,NULL,30); +INSERT INTO emp VALUES (7902,'FORD','ANALYST',7566,'03-DEC-81',3000,NULL,20); +INSERT INTO emp VALUES (7934,'MILLER','CLERK',7782,'23-JAN-82',1300,NULL,10); +-- +-- Load the 'jobhist' table +-- +INSERT INTO jobhist VALUES (7369,'17-DEC-80',NULL,'CLERK',800,NULL,20,'New Hire'); +INSERT INTO jobhist VALUES (7499,'20-FEB-81',NULL,'SALESMAN',1600,300,30,'New Hire'); +INSERT INTO jobhist VALUES (7521,'22-FEB-81',NULL,'SALESMAN',1250,500,30,'New Hire'); +INSERT INTO jobhist VALUES (7566,'02-APR-81',NULL,'MANAGER',2975,NULL,20,'New Hire'); +INSERT INTO jobhist VALUES (7654,'28-SEP-81',NULL,'SALESMAN',1250,1400,30,'New Hire'); +INSERT INTO jobhist VALUES (7698,'01-MAY-81',NULL,'MANAGER',2850,NULL,30,'New Hire'); +INSERT INTO jobhist VALUES (7782,'09-JUN-81',NULL,'MANAGER',2450,NULL,10,'New Hire'); +INSERT INTO jobhist VALUES (7788,'19-APR-87','12-APR-88','CLERK',1000,NULL,20,'New Hire'); +INSERT INTO jobhist VALUES (7788,'13-APR-88','04-MAY-89','CLERK',1040,NULL,20,'Raise'); +INSERT INTO jobhist VALUES (7788,'05-MAY-90',NULL,'ANALYST',3000,NULL,20,'Promoted to Analyst'); +INSERT INTO jobhist VALUES (7839,'17-NOV-81',NULL,'PRESIDENT',5000,NULL,10,'New Hire'); +INSERT INTO jobhist VALUES (7844,'08-SEP-81',NULL,'SALESMAN',1500,0,30,'New Hire'); +INSERT INTO jobhist VALUES (7876,'23-MAY-87',NULL,'CLERK',1100,NULL,20,'New Hire'); +INSERT INTO jobhist VALUES (7900,'03-DEC-81','14-JAN-83','CLERK',950,NULL,10,'New Hire'); +INSERT INTO jobhist VALUES (7900,'15-JAN-83',NULL,'CLERK',950,NULL,30,'Changed to Dept 30'); +INSERT INTO jobhist VALUES (7902,'03-DEC-81',NULL,'ANALYST',3000,NULL,20,'New Hire'); +INSERT INTO jobhist VALUES (7934,'23-JAN-82',NULL,'CLERK',1300,NULL,10,'New Hire'); +-- +-- Populate statistics table and view (pg_statistic/pg_stats) +-- +ANALYZE dept; +ANALYZE emp; +ANALYZE jobhist; +-- +-- Function that lists all employees' numbers and names +-- from the 'emp' table using a cursor. +-- +CREATE OR REPLACE FUNCTION list_emp() RETURNS VOID +AS $$ +DECLARE + v_empno NUMERIC(4); + v_ename VARCHAR(10); + emp_cur CURSOR FOR + SELECT empno, ename FROM emp ORDER BY empno; +BEGIN + OPEN emp_cur; + RAISE INFO 'EMPNO ENAME'; + RAISE INFO '----- -------'; + LOOP + FETCH emp_cur INTO v_empno, v_ename; + EXIT WHEN NOT FOUND; + RAISE INFO '% %', v_empno, v_ename; + END LOOP; + CLOSE emp_cur; + RETURN; +END; +$$ LANGUAGE 'plpgsql'; +-- +-- Function that selects an employee row given the employee +-- number and displays certain columns. +-- +CREATE OR REPLACE FUNCTION select_emp ( + p_empno NUMERIC +) RETURNS VOID +AS $$ +DECLARE + v_ename emp.ename%TYPE; + v_hiredate emp.hiredate%TYPE; + v_sal emp.sal%TYPE; + v_comm emp.comm%TYPE; + v_dname dept.dname%TYPE; + v_disp_date VARCHAR(10); +BEGIN + SELECT INTO + v_ename, v_hiredate, v_sal, v_comm, v_dname + ename, hiredate, sal, COALESCE(comm, 0), dname + FROM emp e, dept d + WHERE empno = p_empno + AND e.deptno = d.deptno; + IF NOT FOUND THEN + RAISE INFO 'Employee % not found', p_empno; + RETURN; + END IF; + v_disp_date := TO_CHAR(v_hiredate, 'MM/DD/YYYY'); + RAISE INFO 'Number : %', p_empno; + RAISE INFO 'Name : %', v_ename; + RAISE INFO 'Hire Date : %', v_disp_date; + RAISE INFO 'Salary : %', v_sal; + RAISE INFO 'Commission: %', v_comm; + RAISE INFO 'Department: %', v_dname; + RETURN; +EXCEPTION + WHEN OTHERS THEN + RAISE INFO 'The following is SQLERRM : %', SQLERRM; + RAISE INFO 'The following is SQLSTATE: %', SQLSTATE; + RETURN; +END; +$$ LANGUAGE 'plpgsql'; +-- +-- A RECORD type used to format the return value of +-- function, 'emp_query'. +-- +CREATE TYPE emp_query_type AS ( + empno NUMERIC, + ename VARCHAR(10), + job VARCHAR(9), + hiredate DATE, + sal NUMERIC +); +-- +-- Function that queries the 'emp' table based on +-- department number and employee number or name. Returns +-- employee number and name as INOUT parameters and job, +-- hire date, and salary as OUT parameters. These are +-- returned in the form of a record defined by +-- RECORD type, 'emp_query_type'. +-- +CREATE OR REPLACE FUNCTION emp_query ( + IN p_deptno NUMERIC, + INOUT p_empno NUMERIC, + INOUT p_ename VARCHAR, + OUT p_job VARCHAR, + OUT p_hiredate DATE, + OUT p_sal NUMERIC +) +AS $$ +BEGIN + SELECT INTO + p_empno, p_ename, p_job, p_hiredate, p_sal + empno, ename, job, hiredate, sal + FROM emp + WHERE deptno = p_deptno + AND (empno = p_empno + OR ename = UPPER(p_ename)); +END; +$$ LANGUAGE 'plpgsql'; +-- +-- Function to call 'emp_query_caller' with IN and INOUT +-- parameters. Displays the results received from INOUT and +-- OUT parameters. +-- +CREATE OR REPLACE FUNCTION emp_query_caller() RETURNS VOID +AS $$ +DECLARE + v_deptno NUMERIC; + v_empno NUMERIC; + v_ename VARCHAR; + v_rows INTEGER; + r_emp_query EMP_QUERY_TYPE; +BEGIN + v_deptno := 30; + v_empno := 0; + v_ename := 'Martin'; + r_emp_query := emp_query(v_deptno, v_empno, v_ename); + RAISE INFO 'Department : %', v_deptno; + RAISE INFO 'Employee No: %', (r_emp_query).empno; + RAISE INFO 'Name : %', (r_emp_query).ename; + RAISE INFO 'Job : %', (r_emp_query).job; + RAISE INFO 'Hire Date : %', (r_emp_query).hiredate; + RAISE INFO 'Salary : %', (r_emp_query).sal; + RETURN; +EXCEPTION + WHEN OTHERS THEN + RAISE INFO 'The following is SQLERRM : %', SQLERRM; + RAISE INFO 'The following is SQLSTATE: %', SQLSTATE; + RETURN; +END; +$$ LANGUAGE 'plpgsql'; +-- +-- Function to compute yearly compensation based on semimonthly +-- salary. +-- +CREATE OR REPLACE FUNCTION emp_comp ( + p_sal NUMERIC, + p_comm NUMERIC +) RETURNS NUMERIC +AS $$ +BEGIN + RETURN (p_sal + COALESCE(p_comm, 0)) * 24; +END; +$$ LANGUAGE 'plpgsql'; +-- +-- Function that gets the next number from sequence, 'next_empno', +-- and ensures it is not already in use as an employee number. +-- +CREATE OR REPLACE FUNCTION new_empno() RETURNS INTEGER +AS $$ +DECLARE + v_cnt INTEGER := 1; + v_new_empno INTEGER; +BEGIN + WHILE v_cnt > 0 LOOP + SELECT INTO v_new_empno nextval('next_empno'); + SELECT INTO v_cnt COUNT(*) FROM emp WHERE empno = v_new_empno; + END LOOP; + RETURN v_new_empno; +END; +$$ LANGUAGE 'plpgsql'; +-- +-- Function that adds a new clerk to table 'emp'. +-- +CREATE OR REPLACE FUNCTION hire_clerk ( + p_ename VARCHAR, + p_deptno NUMERIC +) RETURNS NUMERIC +AS $$ +DECLARE + v_empno NUMERIC(4); + v_ename VARCHAR(10); + v_job VARCHAR(9); + v_mgr NUMERIC(4); + v_hiredate DATE; + v_sal NUMERIC(7,2); + v_comm NUMERIC(7,2); + v_deptno NUMERIC(2); +BEGIN + v_empno := new_empno(); + INSERT INTO emp VALUES (v_empno, p_ename, 'CLERK', 7782, + CURRENT_DATE, 950.00, NULL, p_deptno); + SELECT INTO + v_empno, v_ename, v_job, v_mgr, v_hiredate, v_sal, v_comm, v_deptno + empno, ename, job, mgr, hiredate, sal, comm, deptno + FROM emp WHERE empno = v_empno; + RAISE INFO 'Department : %', v_deptno; + RAISE INFO 'Employee No: %', v_empno; + RAISE INFO 'Name : %', v_ename; + RAISE INFO 'Job : %', v_job; + RAISE INFO 'Manager : %', v_mgr; + RAISE INFO 'Hire Date : %', v_hiredate; + RAISE INFO 'Salary : %', v_sal; + RAISE INFO 'Commission : %', v_comm; + RETURN v_empno; +EXCEPTION + WHEN OTHERS THEN + RAISE INFO 'The following is SQLERRM : %', SQLERRM; + RAISE INFO 'The following is SQLSTATE: %', SQLSTATE; + RETURN -1; +END; +$$ LANGUAGE 'plpgsql'; +-- +-- Function that adds a new salesman to table 'emp'. +-- +CREATE OR REPLACE FUNCTION hire_salesman ( + p_ename VARCHAR, + p_sal NUMERIC, + p_comm NUMERIC +) RETURNS NUMERIC +AS $$ +DECLARE + v_empno NUMERIC(4); + v_ename VARCHAR(10); + v_job VARCHAR(9); + v_mgr NUMERIC(4); + v_hiredate DATE; + v_sal NUMERIC(7,2); + v_comm NUMERIC(7,2); + v_deptno NUMERIC(2); +BEGIN + v_empno := new_empno(); + INSERT INTO emp VALUES (v_empno, p_ename, 'SALESMAN', 7698, + CURRENT_DATE, p_sal, p_comm, 30); + SELECT INTO + v_empno, v_ename, v_job, v_mgr, v_hiredate, v_sal, v_comm, v_deptno + empno, ename, job, mgr, hiredate, sal, comm, deptno + FROM emp WHERE empno = v_empno; + RAISE INFO 'Department : %', v_deptno; + RAISE INFO 'Employee No: %', v_empno; + RAISE INFO 'Name : %', v_ename; + RAISE INFO 'Job : %', v_job; + RAISE INFO 'Manager : %', v_mgr; + RAISE INFO 'Hire Date : %', v_hiredate; + RAISE INFO 'Salary : %', v_sal; + RAISE INFO 'Commission : %', v_comm; + RETURN v_empno; +EXCEPTION + WHEN OTHERS THEN + RAISE INFO 'The following is SQLERRM : %', SQLERRM; + RAISE INFO 'The following is SQLSTATE: %', SQLSTATE; + RETURN -1; +END; +$$ LANGUAGE 'plpgsql'; +-- +-- Rule to INSERT into view 'salesemp' +-- +CREATE OR REPLACE RULE salesemp_i AS ON INSERT TO salesemp +DO INSTEAD + INSERT INTO emp VALUES (NEW.empno, NEW.ename, 'SALESMAN', 7698, + NEW.hiredate, NEW.sal, NEW.comm, 30); +-- +-- Rule to UPDATE view 'salesemp' +-- +CREATE OR REPLACE RULE salesemp_u AS ON UPDATE TO salesemp +DO INSTEAD + UPDATE emp SET empno = NEW.empno, + ename = NEW.ename, + hiredate = NEW.hiredate, + sal = NEW.sal, + comm = NEW.comm + WHERE empno = OLD.empno; +-- +-- Rule to DELETE from view 'salesemp' +-- +CREATE OR REPLACE RULE salesemp_d AS ON DELETE TO salesemp +DO INSTEAD + DELETE FROM emp WHERE empno = OLD.empno; +-- +-- After statement-level trigger that displays a message after +-- an insert, update, or deletion to the 'emp' table. One message +-- per SQL command is displayed. +-- +CREATE OR REPLACE FUNCTION user_audit_trig() RETURNS TRIGGER +AS $$ +DECLARE + v_action VARCHAR(24); + v_text TEXT; +BEGIN + IF TG_OP = 'INSERT' THEN + v_action := ' added employee(s) on '; + ELSIF TG_OP = 'UPDATE' THEN + v_action := ' updated employee(s) on '; + ELSIF TG_OP = 'DELETE' THEN + v_action := ' deleted employee(s) on '; + END IF; +-- v_text := 'User ' || USER || v_action || CURRENT_DATE; Changing this as we need consistent output for regression + v_text := 'User ' || v_action ; + RAISE INFO ' %', v_text; + RETURN NULL; +END; +$$ LANGUAGE 'plpgsql'; +CREATE TRIGGER user_audit_trig + AFTER INSERT OR UPDATE OR DELETE ON emp + FOR EACH STATEMENT EXECUTE PROCEDURE user_audit_trig(); +-- +-- Before row-level trigger that displays employee number and +-- salary of an employee that is about to be added, updated, +-- or deleted in the 'emp' table. +-- +CREATE OR REPLACE FUNCTION emp_sal_trig() RETURNS TRIGGER +AS $$ +DECLARE + sal_diff NUMERIC(7,2); +BEGIN + IF TG_OP = 'INSERT' THEN + RAISE INFO 'Inserting employee %', NEW.empno; + RAISE INFO '..New salary: %', NEW.sal; + RETURN NEW; + END IF; + IF TG_OP = 'UPDATE' THEN + sal_diff := NEW.sal - OLD.sal; + RAISE INFO 'Updating employee %', OLD.empno; + RAISE INFO '..Old salary: %', OLD.sal; + RAISE INFO '..New salary: %', NEW.sal; + RAISE INFO '..Raise : %', sal_diff; + RETURN NEW; + END IF; + IF TG_OP = 'DELETE' THEN + RAISE INFO 'Deleting employee %', OLD.empno; + RAISE INFO '..Old salary: %', OLD.sal; + RETURN OLD; + END IF; +END; +$$ LANGUAGE 'plpgsql'; +CREATE TRIGGER emp_sal_trig + BEFORE DELETE OR INSERT OR UPDATE ON emp + FOR EACH ROW EXECUTE PROCEDURE emp_sal_trig(); +COMMIT; +SELECT * FROM emp; + empno | ename | job | mgr | hiredate | sal | comm | deptno +-------+--------+-----------+------+------------+---------+---------+-------- + 7369 | SMITH | CLERK | 7902 | 1980-12-17 | 800.00 | | 20 + 7499 | ALLEN | SALESMAN | 7698 | 1981-02-20 | 1600.00 | 300.00 | 30 + 7521 | WARD | SALESMAN | 7698 | 1981-02-22 | 1250.00 | 500.00 | 30 + 7566 | JONES | MANAGER | 7839 | 1981-04-02 | 2975.00 | | 20 + 7654 | MARTIN | SALESMAN | 7698 | 1981-09-28 | 1250.00 | 1400.00 | 30 + 7698 | BLAKE | MANAGER | 7839 | 1981-05-01 | 2850.00 | | 30 + 7782 | CLARK | MANAGER | 7839 | 1981-06-09 | 2450.00 | | 10 + 7788 | SCOTT | ANALYST | 7566 | 1987-04-19 | 3000.00 | | 20 + 7839 | KING | PRESIDENT | | 1981-11-17 | 5000.00 | | 10 + 7844 | TURNER | SALESMAN | 7698 | 1981-09-08 | 1500.00 | 0.00 | 30 + 7876 | ADAMS | CLERK | 7788 | 1987-05-23 | 1100.00 | | 20 + 7900 | JAMES | CLERK | 7698 | 1981-12-03 | 950.00 | | 30 + 7902 | FORD | ANALYST | 7566 | 1981-12-03 | 3000.00 | | 20 + 7934 | MILLER | CLERK | 7782 | 1982-01-23 | 1300.00 | | 10 +(14 rows) + +SELECT * FROM dept; + deptno | dname | loc +--------+------------+---------- + 10 | ACCOUNTING | NEW YORK + 20 | RESEARCH | DALLAS + 30 | SALES | CHICAGO + 40 | OPERATIONS | BOSTON +(4 rows) + +SELECT * FROM jobhist; + empno | startdate | enddate | job | sal | comm | deptno | chgdesc +-------+---------------------+---------------------+-----------+---------+---------+--------+--------------------- + 7369 | 1980-12-17 00:00:00 | | CLERK | 800.00 | | 20 | New Hire + 7499 | 1981-02-20 00:00:00 | | SALESMAN | 1600.00 | 300.00 | 30 | New Hire + 7521 | 1981-02-22 00:00:00 | | SALESMAN | 1250.00 | 500.00 | 30 | New Hire + 7566 | 1981-04-02 00:00:00 | | MANAGER | 2975.00 | | 20 | New Hire + 7654 | 1981-09-28 00:00:00 | | SALESMAN | 1250.00 | 1400.00 | 30 | New Hire + 7698 | 1981-05-01 00:00:00 | | MANAGER | 2850.00 | | 30 | New Hire + 7782 | 1981-06-09 00:00:00 | | MANAGER | 2450.00 | | 10 | New Hire + 7788 | 1987-04-19 00:00:00 | 1988-04-12 00:00:00 | CLERK | 1000.00 | | 20 | New Hire + 7788 | 1988-04-13 00:00:00 | 1989-05-04 00:00:00 | CLERK | 1040.00 | | 20 | Raise + 7788 | 1990-05-05 00:00:00 | | ANALYST | 3000.00 | | 20 | Promoted to Analyst + 7839 | 1981-11-17 00:00:00 | | PRESIDENT | 5000.00 | | 10 | New Hire + 7844 | 1981-09-08 00:00:00 | | SALESMAN | 1500.00 | 0.00 | 30 | New Hire + 7876 | 1987-05-23 00:00:00 | | CLERK | 1100.00 | | 20 | New Hire + 7900 | 1981-12-03 00:00:00 | 1983-01-14 00:00:00 | CLERK | 950.00 | | 10 | New Hire + 7900 | 1983-01-15 00:00:00 | | CLERK | 950.00 | | 30 | Changed to Dept 30 + 7902 | 1981-12-03 00:00:00 | | ANALYST | 3000.00 | | 20 | New Hire + 7934 | 1982-01-23 00:00:00 | | CLERK | 1300.00 | | 10 | New Hire +(17 rows) + +-- Now test the crash fix +DELETE FROM emp WHERE empno = 7934; +INFO: Deleting employee 7934 +INFO: ..Old salary: 1300.00 +INFO: User deleted employee(s) on +DELETE FROM emp WHERE empno = 7698; +INFO: Deleting employee 7698 +INFO: ..Old salary: 2850.00 +INFO: User deleted employee(s) on +DELETE FROM emp WHERE empno = 7782; +INFO: Deleting employee 7782 +INFO: ..Old salary: 2450.00 +INFO: User deleted employee(s) on +DELETE FROM emp WHERE empno = 7788; +INFO: Deleting employee 7788 +INFO: ..Old salary: 3000.00 +INFO: User deleted employee(s) on +DELETE FROM emp WHERE empno = 7838; +INFO: User deleted employee(s) on +DELETE FROM emp WHERE empno = 7900; +INFO: Deleting employee 7900 +INFO: ..Old salary: 950.00 +INFO: User deleted employee(s) on +DELETE FROM emp WHERE empno = 7654; +INFO: Deleting employee 7654 +INFO: ..Old salary: 1250.00 +INFO: User deleted employee(s) on +DELETE FROM dept WHERE deptno = 40; +SELECT * FROM emp; + empno | ename | job | mgr | hiredate | sal | comm | deptno +-------+--------+-----------+------+------------+---------+--------+-------- + 7369 | SMITH | CLERK | 7902 | 1980-12-17 | 800.00 | | 20 + 7499 | ALLEN | SALESMAN | 7698 | 1981-02-20 | 1600.00 | 300.00 | 30 + 7521 | WARD | SALESMAN | 7698 | 1981-02-22 | 1250.00 | 500.00 | 30 + 7566 | JONES | MANAGER | 7839 | 1981-04-02 | 2975.00 | | 20 + 7839 | KING | PRESIDENT | | 1981-11-17 | 5000.00 | | 10 + 7844 | TURNER | SALESMAN | 7698 | 1981-09-08 | 1500.00 | 0.00 | 30 + 7876 | ADAMS | CLERK | 7788 | 1987-05-23 | 1100.00 | | 20 + 7902 | FORD | ANALYST | 7566 | 1981-12-03 | 3000.00 | | 20 +(8 rows) + +SELECT * FROM dept; + deptno | dname | loc +--------+------------+---------- + 10 | ACCOUNTING | NEW YORK + 20 | RESEARCH | DALLAS + 30 | SALES | CHICAGO +(3 rows) + +SELECT * FROM jobhist; + empno | startdate | enddate | job | sal | comm | deptno | chgdesc +-------+---------------------+---------+-----------+---------+--------+--------+---------- + 7369 | 1980-12-17 00:00:00 | | CLERK | 800.00 | | 20 | New Hire + 7499 | 1981-02-20 00:00:00 | | SALESMAN | 1600.00 | 300.00 | 30 | New Hire + 7521 | 1981-02-22 00:00:00 | | SALESMAN | 1250.00 | 500.00 | 30 | New Hire + 7566 | 1981-04-02 00:00:00 | | MANAGER | 2975.00 | | 20 | New Hire + 7839 | 1981-11-17 00:00:00 | | PRESIDENT | 5000.00 | | 10 | New Hire + 7844 | 1981-09-08 00:00:00 | | SALESMAN | 1500.00 | 0.00 | 30 | New Hire + 7876 | 1987-05-23 00:00:00 | | CLERK | 1100.00 | | 20 | New Hire + 7902 | 1981-12-03 00:00:00 | | ANALYST | 3000.00 | | 20 | New Hire +(8 rows) + +DROP TABLE jobhist CASCADE; +DROP TABLE emp CASCADE; +NOTICE: drop cascades to view salesemp +DROP TABLE dept CASCADE; +DROP EXTENSION pg_tde CASCADE; diff --git a/meson.build b/meson.build index 0d69b19b..366770e0 100644 --- a/meson.build +++ b/meson.build @@ -85,6 +85,7 @@ tests += { 'non_sorted_off_compact', 'update_compare_indexes', 'pgtde_is_encrypted', + 'test_issue_153_fix', 'multi_insert', 'keyprovider_dependency', 'trigger_on_view', diff --git a/sql/test_issue_153_fix.sql b/sql/test_issue_153_fix.sql new file mode 100644 index 00000000..17a665a0 --- /dev/null +++ b/sql/test_issue_153_fix.sql @@ -0,0 +1,483 @@ +CREATE EXTENSION pg_tde; +SET datestyle TO 'iso, dmy'; + +SELECT * FROM pg_tde_master_key_info(); + +SELECT pg_tde_add_key_provider_file('file-ring','/tmp/pg_tde_test_keyring.per'); +SELECT pg_tde_set_master_key('test-db-master-key','file-ring'); + +-- +-- Script that creates the 'sample' tde encrypted tables, views +-- functions, triggers, etc. +-- +-- Start new transaction - commit all or nothing +-- +BEGIN; +-- +-- Create and load tables used in the documentation examples. +-- +-- Create the 'dept' table +-- +CREATE TABLE dept ( + deptno NUMERIC(2) NOT NULL CONSTRAINT dept_pk PRIMARY KEY, + dname VARCHAR(14) CONSTRAINT dept_dname_uq UNIQUE, + loc VARCHAR(13) +)using pg_tde; +-- +-- Create the 'emp' table +-- +CREATE TABLE emp ( + empno NUMERIC(4) NOT NULL CONSTRAINT emp_pk PRIMARY KEY, + ename VARCHAR(10), + job VARCHAR(9), + mgr NUMERIC(4), + hiredate DATE, + sal NUMERIC(7,2) CONSTRAINT emp_sal_ck CHECK (sal > 0), + comm NUMERIC(7,2), + deptno NUMERIC(2) CONSTRAINT emp_ref_dept_fk + REFERENCES dept(deptno) +)using pg_tde; +-- +-- Create the 'jobhist' table +-- +CREATE TABLE jobhist ( + empno NUMERIC(4) NOT NULL, + startdate TIMESTAMP(0) NOT NULL, + enddate TIMESTAMP(0), + job VARCHAR(9), + sal NUMERIC(7,2), + comm NUMERIC(7,2), + deptno NUMERIC(2), + chgdesc VARCHAR(80), + CONSTRAINT jobhist_pk PRIMARY KEY (empno, startdate), + CONSTRAINT jobhist_ref_emp_fk FOREIGN KEY (empno) + REFERENCES emp(empno) ON DELETE CASCADE, + CONSTRAINT jobhist_ref_dept_fk FOREIGN KEY (deptno) + REFERENCES dept (deptno) ON DELETE SET NULL, + CONSTRAINT jobhist_date_chk CHECK (startdate <= enddate) +)using pg_tde; +-- +-- Create the 'salesemp' view +-- +CREATE OR REPLACE VIEW salesemp AS + SELECT empno, ename, hiredate, sal, comm FROM emp WHERE job = 'SALESMAN'; +-- +-- Sequence to generate values for function 'new_empno'. +-- +CREATE SEQUENCE next_empno START WITH 8000 INCREMENT BY 1; +-- +-- Issue PUBLIC grants +-- +GRANT ALL ON emp TO PUBLIC; +GRANT ALL ON dept TO PUBLIC; +GRANT ALL ON jobhist TO PUBLIC; +GRANT ALL ON salesemp TO PUBLIC; +GRANT ALL ON next_empno TO PUBLIC; +-- +-- Load the 'dept' table +-- +INSERT INTO dept VALUES (10,'ACCOUNTING','NEW YORK'); +INSERT INTO dept VALUES (20,'RESEARCH','DALLAS'); +INSERT INTO dept VALUES (30,'SALES','CHICAGO'); +INSERT INTO dept VALUES (40,'OPERATIONS','BOSTON'); +-- +-- Load the 'emp' table +-- +INSERT INTO emp VALUES (7369,'SMITH','CLERK',7902,'17-DEC-80',800,NULL,20); +INSERT INTO emp VALUES (7499,'ALLEN','SALESMAN',7698,'20-FEB-81',1600,300,30); +INSERT INTO emp VALUES (7521,'WARD','SALESMAN',7698,'22-FEB-81',1250,500,30); +INSERT INTO emp VALUES (7566,'JONES','MANAGER',7839,'02-APR-81',2975,NULL,20); +INSERT INTO emp VALUES (7654,'MARTIN','SALESMAN',7698,'28-SEP-81',1250,1400,30); +INSERT INTO emp VALUES (7698,'BLAKE','MANAGER',7839,'01-MAY-81',2850,NULL,30); +INSERT INTO emp VALUES (7782,'CLARK','MANAGER',7839,'09-JUN-81',2450,NULL,10); +INSERT INTO emp VALUES (7788,'SCOTT','ANALYST',7566,'19-APR-87',3000,NULL,20); +INSERT INTO emp VALUES (7839,'KING','PRESIDENT',NULL,'17-NOV-81',5000,NULL,10); +INSERT INTO emp VALUES (7844,'TURNER','SALESMAN',7698,'08-SEP-81',1500,0,30); +INSERT INTO emp VALUES (7876,'ADAMS','CLERK',7788,'23-MAY-87',1100,NULL,20); +INSERT INTO emp VALUES (7900,'JAMES','CLERK',7698,'03-DEC-81',950,NULL,30); +INSERT INTO emp VALUES (7902,'FORD','ANALYST',7566,'03-DEC-81',3000,NULL,20); +INSERT INTO emp VALUES (7934,'MILLER','CLERK',7782,'23-JAN-82',1300,NULL,10); +-- +-- Load the 'jobhist' table +-- +INSERT INTO jobhist VALUES (7369,'17-DEC-80',NULL,'CLERK',800,NULL,20,'New Hire'); +INSERT INTO jobhist VALUES (7499,'20-FEB-81',NULL,'SALESMAN',1600,300,30,'New Hire'); +INSERT INTO jobhist VALUES (7521,'22-FEB-81',NULL,'SALESMAN',1250,500,30,'New Hire'); +INSERT INTO jobhist VALUES (7566,'02-APR-81',NULL,'MANAGER',2975,NULL,20,'New Hire'); +INSERT INTO jobhist VALUES (7654,'28-SEP-81',NULL,'SALESMAN',1250,1400,30,'New Hire'); +INSERT INTO jobhist VALUES (7698,'01-MAY-81',NULL,'MANAGER',2850,NULL,30,'New Hire'); +INSERT INTO jobhist VALUES (7782,'09-JUN-81',NULL,'MANAGER',2450,NULL,10,'New Hire'); +INSERT INTO jobhist VALUES (7788,'19-APR-87','12-APR-88','CLERK',1000,NULL,20,'New Hire'); +INSERT INTO jobhist VALUES (7788,'13-APR-88','04-MAY-89','CLERK',1040,NULL,20,'Raise'); +INSERT INTO jobhist VALUES (7788,'05-MAY-90',NULL,'ANALYST',3000,NULL,20,'Promoted to Analyst'); +INSERT INTO jobhist VALUES (7839,'17-NOV-81',NULL,'PRESIDENT',5000,NULL,10,'New Hire'); +INSERT INTO jobhist VALUES (7844,'08-SEP-81',NULL,'SALESMAN',1500,0,30,'New Hire'); +INSERT INTO jobhist VALUES (7876,'23-MAY-87',NULL,'CLERK',1100,NULL,20,'New Hire'); +INSERT INTO jobhist VALUES (7900,'03-DEC-81','14-JAN-83','CLERK',950,NULL,10,'New Hire'); +INSERT INTO jobhist VALUES (7900,'15-JAN-83',NULL,'CLERK',950,NULL,30,'Changed to Dept 30'); +INSERT INTO jobhist VALUES (7902,'03-DEC-81',NULL,'ANALYST',3000,NULL,20,'New Hire'); +INSERT INTO jobhist VALUES (7934,'23-JAN-82',NULL,'CLERK',1300,NULL,10,'New Hire'); +-- +-- Populate statistics table and view (pg_statistic/pg_stats) +-- +ANALYZE dept; +ANALYZE emp; +ANALYZE jobhist; +-- +-- Function that lists all employees' numbers and names +-- from the 'emp' table using a cursor. +-- +CREATE OR REPLACE FUNCTION list_emp() RETURNS VOID +AS $$ +DECLARE + v_empno NUMERIC(4); + v_ename VARCHAR(10); + emp_cur CURSOR FOR + SELECT empno, ename FROM emp ORDER BY empno; +BEGIN + OPEN emp_cur; + RAISE INFO 'EMPNO ENAME'; + RAISE INFO '----- -------'; + LOOP + FETCH emp_cur INTO v_empno, v_ename; + EXIT WHEN NOT FOUND; + RAISE INFO '% %', v_empno, v_ename; + END LOOP; + CLOSE emp_cur; + RETURN; +END; +$$ LANGUAGE 'plpgsql'; +-- +-- Function that selects an employee row given the employee +-- number and displays certain columns. +-- +CREATE OR REPLACE FUNCTION select_emp ( + p_empno NUMERIC +) RETURNS VOID +AS $$ +DECLARE + v_ename emp.ename%TYPE; + v_hiredate emp.hiredate%TYPE; + v_sal emp.sal%TYPE; + v_comm emp.comm%TYPE; + v_dname dept.dname%TYPE; + v_disp_date VARCHAR(10); +BEGIN + SELECT INTO + v_ename, v_hiredate, v_sal, v_comm, v_dname + ename, hiredate, sal, COALESCE(comm, 0), dname + FROM emp e, dept d + WHERE empno = p_empno + AND e.deptno = d.deptno; + IF NOT FOUND THEN + RAISE INFO 'Employee % not found', p_empno; + RETURN; + END IF; + v_disp_date := TO_CHAR(v_hiredate, 'MM/DD/YYYY'); + RAISE INFO 'Number : %', p_empno; + RAISE INFO 'Name : %', v_ename; + RAISE INFO 'Hire Date : %', v_disp_date; + RAISE INFO 'Salary : %', v_sal; + RAISE INFO 'Commission: %', v_comm; + RAISE INFO 'Department: %', v_dname; + RETURN; +EXCEPTION + WHEN OTHERS THEN + RAISE INFO 'The following is SQLERRM : %', SQLERRM; + RAISE INFO 'The following is SQLSTATE: %', SQLSTATE; + RETURN; +END; +$$ LANGUAGE 'plpgsql'; +-- +-- A RECORD type used to format the return value of +-- function, 'emp_query'. +-- +CREATE TYPE emp_query_type AS ( + empno NUMERIC, + ename VARCHAR(10), + job VARCHAR(9), + hiredate DATE, + sal NUMERIC +); +-- +-- Function that queries the 'emp' table based on +-- department number and employee number or name. Returns +-- employee number and name as INOUT parameters and job, +-- hire date, and salary as OUT parameters. These are +-- returned in the form of a record defined by +-- RECORD type, 'emp_query_type'. +-- +CREATE OR REPLACE FUNCTION emp_query ( + IN p_deptno NUMERIC, + INOUT p_empno NUMERIC, + INOUT p_ename VARCHAR, + OUT p_job VARCHAR, + OUT p_hiredate DATE, + OUT p_sal NUMERIC +) +AS $$ +BEGIN + SELECT INTO + p_empno, p_ename, p_job, p_hiredate, p_sal + empno, ename, job, hiredate, sal + FROM emp + WHERE deptno = p_deptno + AND (empno = p_empno + OR ename = UPPER(p_ename)); +END; +$$ LANGUAGE 'plpgsql'; +-- +-- Function to call 'emp_query_caller' with IN and INOUT +-- parameters. Displays the results received from INOUT and +-- OUT parameters. +-- +CREATE OR REPLACE FUNCTION emp_query_caller() RETURNS VOID +AS $$ +DECLARE + v_deptno NUMERIC; + v_empno NUMERIC; + v_ename VARCHAR; + v_rows INTEGER; + r_emp_query EMP_QUERY_TYPE; +BEGIN + v_deptno := 30; + v_empno := 0; + v_ename := 'Martin'; + r_emp_query := emp_query(v_deptno, v_empno, v_ename); + RAISE INFO 'Department : %', v_deptno; + RAISE INFO 'Employee No: %', (r_emp_query).empno; + RAISE INFO 'Name : %', (r_emp_query).ename; + RAISE INFO 'Job : %', (r_emp_query).job; + RAISE INFO 'Hire Date : %', (r_emp_query).hiredate; + RAISE INFO 'Salary : %', (r_emp_query).sal; + RETURN; +EXCEPTION + WHEN OTHERS THEN + RAISE INFO 'The following is SQLERRM : %', SQLERRM; + RAISE INFO 'The following is SQLSTATE: %', SQLSTATE; + RETURN; +END; +$$ LANGUAGE 'plpgsql'; +-- +-- Function to compute yearly compensation based on semimonthly +-- salary. +-- +CREATE OR REPLACE FUNCTION emp_comp ( + p_sal NUMERIC, + p_comm NUMERIC +) RETURNS NUMERIC +AS $$ +BEGIN + RETURN (p_sal + COALESCE(p_comm, 0)) * 24; +END; +$$ LANGUAGE 'plpgsql'; +-- +-- Function that gets the next number from sequence, 'next_empno', +-- and ensures it is not already in use as an employee number. +-- +CREATE OR REPLACE FUNCTION new_empno() RETURNS INTEGER +AS $$ +DECLARE + v_cnt INTEGER := 1; + v_new_empno INTEGER; +BEGIN + WHILE v_cnt > 0 LOOP + SELECT INTO v_new_empno nextval('next_empno'); + SELECT INTO v_cnt COUNT(*) FROM emp WHERE empno = v_new_empno; + END LOOP; + RETURN v_new_empno; +END; +$$ LANGUAGE 'plpgsql'; +-- +-- Function that adds a new clerk to table 'emp'. +-- +CREATE OR REPLACE FUNCTION hire_clerk ( + p_ename VARCHAR, + p_deptno NUMERIC +) RETURNS NUMERIC +AS $$ +DECLARE + v_empno NUMERIC(4); + v_ename VARCHAR(10); + v_job VARCHAR(9); + v_mgr NUMERIC(4); + v_hiredate DATE; + v_sal NUMERIC(7,2); + v_comm NUMERIC(7,2); + v_deptno NUMERIC(2); +BEGIN + v_empno := new_empno(); + INSERT INTO emp VALUES (v_empno, p_ename, 'CLERK', 7782, + CURRENT_DATE, 950.00, NULL, p_deptno); + SELECT INTO + v_empno, v_ename, v_job, v_mgr, v_hiredate, v_sal, v_comm, v_deptno + empno, ename, job, mgr, hiredate, sal, comm, deptno + FROM emp WHERE empno = v_empno; + RAISE INFO 'Department : %', v_deptno; + RAISE INFO 'Employee No: %', v_empno; + RAISE INFO 'Name : %', v_ename; + RAISE INFO 'Job : %', v_job; + RAISE INFO 'Manager : %', v_mgr; + RAISE INFO 'Hire Date : %', v_hiredate; + RAISE INFO 'Salary : %', v_sal; + RAISE INFO 'Commission : %', v_comm; + RETURN v_empno; +EXCEPTION + WHEN OTHERS THEN + RAISE INFO 'The following is SQLERRM : %', SQLERRM; + RAISE INFO 'The following is SQLSTATE: %', SQLSTATE; + RETURN -1; +END; +$$ LANGUAGE 'plpgsql'; +-- +-- Function that adds a new salesman to table 'emp'. +-- +CREATE OR REPLACE FUNCTION hire_salesman ( + p_ename VARCHAR, + p_sal NUMERIC, + p_comm NUMERIC +) RETURNS NUMERIC +AS $$ +DECLARE + v_empno NUMERIC(4); + v_ename VARCHAR(10); + v_job VARCHAR(9); + v_mgr NUMERIC(4); + v_hiredate DATE; + v_sal NUMERIC(7,2); + v_comm NUMERIC(7,2); + v_deptno NUMERIC(2); +BEGIN + v_empno := new_empno(); + INSERT INTO emp VALUES (v_empno, p_ename, 'SALESMAN', 7698, + CURRENT_DATE, p_sal, p_comm, 30); + SELECT INTO + v_empno, v_ename, v_job, v_mgr, v_hiredate, v_sal, v_comm, v_deptno + empno, ename, job, mgr, hiredate, sal, comm, deptno + FROM emp WHERE empno = v_empno; + RAISE INFO 'Department : %', v_deptno; + RAISE INFO 'Employee No: %', v_empno; + RAISE INFO 'Name : %', v_ename; + RAISE INFO 'Job : %', v_job; + RAISE INFO 'Manager : %', v_mgr; + RAISE INFO 'Hire Date : %', v_hiredate; + RAISE INFO 'Salary : %', v_sal; + RAISE INFO 'Commission : %', v_comm; + RETURN v_empno; +EXCEPTION + WHEN OTHERS THEN + RAISE INFO 'The following is SQLERRM : %', SQLERRM; + RAISE INFO 'The following is SQLSTATE: %', SQLSTATE; + RETURN -1; +END; +$$ LANGUAGE 'plpgsql'; +-- +-- Rule to INSERT into view 'salesemp' +-- +CREATE OR REPLACE RULE salesemp_i AS ON INSERT TO salesemp +DO INSTEAD + INSERT INTO emp VALUES (NEW.empno, NEW.ename, 'SALESMAN', 7698, + NEW.hiredate, NEW.sal, NEW.comm, 30); +-- +-- Rule to UPDATE view 'salesemp' +-- +CREATE OR REPLACE RULE salesemp_u AS ON UPDATE TO salesemp +DO INSTEAD + UPDATE emp SET empno = NEW.empno, + ename = NEW.ename, + hiredate = NEW.hiredate, + sal = NEW.sal, + comm = NEW.comm + WHERE empno = OLD.empno; +-- +-- Rule to DELETE from view 'salesemp' +-- +CREATE OR REPLACE RULE salesemp_d AS ON DELETE TO salesemp +DO INSTEAD + DELETE FROM emp WHERE empno = OLD.empno; +-- +-- After statement-level trigger that displays a message after +-- an insert, update, or deletion to the 'emp' table. One message +-- per SQL command is displayed. +-- +CREATE OR REPLACE FUNCTION user_audit_trig() RETURNS TRIGGER +AS $$ +DECLARE + v_action VARCHAR(24); + v_text TEXT; +BEGIN + IF TG_OP = 'INSERT' THEN + v_action := ' added employee(s) on '; + ELSIF TG_OP = 'UPDATE' THEN + v_action := ' updated employee(s) on '; + ELSIF TG_OP = 'DELETE' THEN + v_action := ' deleted employee(s) on '; + END IF; +-- v_text := 'User ' || USER || v_action || CURRENT_DATE; Changing this as we need consistent output for regression + v_text := 'User ' || v_action ; + RAISE INFO ' %', v_text; + RETURN NULL; +END; +$$ LANGUAGE 'plpgsql'; +CREATE TRIGGER user_audit_trig + AFTER INSERT OR UPDATE OR DELETE ON emp + FOR EACH STATEMENT EXECUTE PROCEDURE user_audit_trig(); +-- +-- Before row-level trigger that displays employee number and +-- salary of an employee that is about to be added, updated, +-- or deleted in the 'emp' table. +-- +CREATE OR REPLACE FUNCTION emp_sal_trig() RETURNS TRIGGER +AS $$ +DECLARE + sal_diff NUMERIC(7,2); +BEGIN + IF TG_OP = 'INSERT' THEN + RAISE INFO 'Inserting employee %', NEW.empno; + RAISE INFO '..New salary: %', NEW.sal; + RETURN NEW; + END IF; + IF TG_OP = 'UPDATE' THEN + sal_diff := NEW.sal - OLD.sal; + RAISE INFO 'Updating employee %', OLD.empno; + RAISE INFO '..Old salary: %', OLD.sal; + RAISE INFO '..New salary: %', NEW.sal; + RAISE INFO '..Raise : %', sal_diff; + RETURN NEW; + END IF; + IF TG_OP = 'DELETE' THEN + RAISE INFO 'Deleting employee %', OLD.empno; + RAISE INFO '..Old salary: %', OLD.sal; + RETURN OLD; + END IF; +END; +$$ LANGUAGE 'plpgsql'; +CREATE TRIGGER emp_sal_trig + BEFORE DELETE OR INSERT OR UPDATE ON emp + FOR EACH ROW EXECUTE PROCEDURE emp_sal_trig(); +COMMIT; + +SELECT * FROM emp; +SELECT * FROM dept; +SELECT * FROM jobhist; + +-- Now test the crash fix +DELETE FROM emp WHERE empno = 7934; +DELETE FROM emp WHERE empno = 7698; +DELETE FROM emp WHERE empno = 7782; +DELETE FROM emp WHERE empno = 7788; +DELETE FROM emp WHERE empno = 7838; +DELETE FROM emp WHERE empno = 7900; +DELETE FROM emp WHERE empno = 7654; + +DELETE FROM dept WHERE deptno = 40; + +SELECT * FROM emp; +SELECT * FROM dept; +SELECT * FROM jobhist; + +DROP TABLE jobhist CASCADE; +DROP TABLE emp CASCADE; +DROP TABLE dept CASCADE; + +DROP EXTENSION pg_tde CASCADE; diff --git a/src/encryption/enc_tde.c b/src/encryption/enc_tde.c index 0a489c5d..6b61892b 100644 --- a/src/encryption/enc_tde.c +++ b/src/encryption/enc_tde.c @@ -20,16 +20,13 @@ static void iv_prefix_debug(const char* iv_prefix, char* out_hex) #endif static void -SetIVPrefix(ItemPointerData* ip, CommandId cid, char* iv_prefix) +SetIVPrefix(ItemPointerData* ip, char* iv_prefix) { /* We have up to 16 bytes for the entire IV * The higher bytes (starting with 15) are used for the incrementing counter * The lower bytes (in this case, 0..5) are used for the tuple identification * Tuple identification is based on CTID, which currently is 48 bytes in * postgres: 4 bytes for the block id and 2 bytes for the position id - * After the CTID, we also add the CommandID, which is 4 bytes - * This ensures that even when postgres reuses the same CTID in time, - * with the different CID we still have a unique IV. */ iv_prefix[0] = ip->ip_blkid.bi_hi / 256; iv_prefix[1] = ip->ip_blkid.bi_hi % 256; @@ -37,7 +34,6 @@ SetIVPrefix(ItemPointerData* ip, CommandId cid, char* iv_prefix) iv_prefix[3] = ip->ip_blkid.bi_lo % 256; iv_prefix[4] = ip->ip_posid / 256; iv_prefix[5] = ip->ip_posid % 256; - memcpy(iv_prefix + 6, &cid, 4); } /* @@ -182,7 +178,7 @@ pg_tde_crypt_tuple(HeapTuple tuple, HeapTuple out_tuple, RelKeyData* key, const char *tup_data = (char*)tuple->t_data + tuple->t_data->t_hoff; char *out_data = (char*)out_tuple->t_data + out_tuple->t_data->t_hoff; - SetIVPrefix(&tuple->t_self, tuple->t_data->t_choice.t_heap.t_field3.t_cid, iv_prefix); + SetIVPrefix(&tuple->t_self, iv_prefix); #ifdef ENCRYPTION_DEBUG ereport(LOG, @@ -221,7 +217,7 @@ PGTdePageAddItemExtended(RelFileLocator rel, ItemPointerSet(&ip, bn, off); - SetIVPrefix(&ip, ((HeapTupleHeader)item)->t_choice.t_heap.t_field3.t_cid, iv_prefix); + SetIVPrefix(&ip, iv_prefix); PG_TDE_ENCRYPT_PAGE_ITEM(iv_prefix, 0, data, data_len, toAddr, key); return off;