pod-upgrade-0.2.0_to_0.3.0.sql 2.6KB

12345678910111213141516171819202122232425262728293031323334353637383940414243
  1. -- move table
  2. ALTER TABLE pod_nodes RENAME TO pod_nodes_history;
  3. -- add uuid index
  4. -- drop primary key
  5. -- new primary key
  6. CREATE SEQUENCE pod_nodes_version_id_sequence;
  7. ALTER TABLE pod_nodes_history
  8. DROP CONSTRAINT pod_nodes_pk CASCADE,
  9. ADD COLUMN version_id INTEGER PRIMARY KEY DEFAULT nextval('pod_nodes_version_id_sequence');
  10. -- create view
  11. CREATE OR REPLACE VIEW pod_nodes AS
  12. SELECT DISTINCT ON (node_id) node_id, parent_id, node_order, node_type, created_at, updated_at,
  13. data_label, data_content, data_datetime, node_status, data_reminder_datetime,
  14. data_file_name, data_file_content, data_file_mime_type, parent_tree_path,
  15. node_depth, owner_id
  16. FROM pod_nodes_history
  17. ORDER BY node_id, updated_at DESC;
  18. CREATE OR REPLACE RULE pod_insert_new_node AS ON INSERT
  19. TO pod_nodes
  20. DO INSTEAD INSERT INTO pod_nodes_history (node_id, parent_id, node_order, node_type, created_at, updated_at,
  21. data_label, data_content, data_datetime, node_status, data_reminder_datetime,
  22. data_file_name, data_file_content, data_file_mime_type, parent_tree_path,
  23. node_depth, owner_id, version_id) VALUES (nextval('pod_nodes__node_id__sequence'), NEW.parent_id, NEW.node_order, NEW.node_type, NEW.created_at, NEW.updated_at, NEW.data_label, NEW.data_content, NEW.data_datetime, NEW.node_status, NEW.data_reminder_datetime, NEW.data_file_name, NEW.data_file_content, NEW.data_file_mime_type, NEW.parent_tree_path, NEW.node_depth, NEW.owner_id, nextval('pod_nodes_version_id_sequence'))
  24. RETURNING node_id, parent_id, node_order, node_type, created_at, updated_at,
  25. data_label, data_content, data_datetime, node_status, data_reminder_datetime,
  26. data_file_name, data_file_content, data_file_mime_type, parent_tree_path,
  27. node_depth, owner_id;
  28. CREATE OR REPLACE FUNCTION pod_update_node() RETURNS trigger AS $$
  29. BEGIN
  30. INSERT INTO pod_nodes_history (node_id, parent_id, node_order, node_type, created_at, updated_at,
  31. data_label, data_content, data_datetime, node_status, data_reminder_datetime,
  32. data_file_name, data_file_content, data_file_mime_type, parent_tree_path,
  33. node_depth, owner_id, version_id) VALUES (NEW.node_id, NEW.parent_id, NEW.node_order, NEW.node_type, NEW.created_at, NEW.updated_at, NEW.data_label, NEW.data_content, NEW.data_datetime, NEW.node_status, NEW.data_reminder_datetime, NEW.data_file_name, NEW.data_file_content, NEW.data_file_mime_type, NEW.parent_tree_path, NEW.node_depth, NEW.owner_id, nextval('pod_nodes_version_id_sequence'));
  34. return new;
  35. END;
  36. $$ LANGUAGE plpgsql;
  37. CREATE TRIGGER pod_update_node_tg INSTEAD OF UPDATE ON pod_nodes FOR EACH ROW EXECUTE PROCEDURE pod_update_node();