CREATE TYPE json_ancestor_array as ("Ancestors" varchar[]); CREATE OR REPLACE PROCEDURE add_nodes(p_user_id int4, p_client_uuid varchar, p_nodes jsonb) LANGUAGE PLPGSQL AS $$ DECLARE node_data jsonb; node_updated timestamptz; db_updated timestamptz; db_uuid bpchar; db_client bpchar; db_client_seq int; node_uuid bpchar; BEGIN RAISE NOTICE '--------------------------'; FOR node_data IN SELECT * FROM jsonb_array_elements(p_nodes) LOOP node_uuid = (node_data->>'UUID')::bpchar; node_updated = (node_data->>'Updated')::timestamptz; /* Retrieve the current modified timestamp for this node from the database. */ SELECT uuid, updated, client, client_sequence INTO db_uuid, db_updated, db_client, db_client_seq FROM public."node" WHERE user_id = p_user_id AND uuid = node_uuid; /* Is the node not in database? It needs to be created. */ IF db_uuid IS NULL THEN RAISE NOTICE '01 New node %', node_uuid; INSERT INTO public."node" ( user_id, "uuid", parent_uuid, created, updated, "name", "content", markdown, "content_encrypted", client, client_sequence ) VALUES( p_user_id, node_uuid, (node_data->>'ParentUUID')::bpchar, (node_data->>'Created')::timestamptz, (node_data->>'Updated')::timestamptz, (node_data->>'Name')::varchar, (node_data->>'Content')::text, (node_data->>'Markdown')::bool, '', /* content_encrypted */ p_client_uuid, (node_data->>'ClientSequence')::int ); CONTINUE; END IF; /* The client could send a specific node again if it didn't receive the OK from this procedure before. */ IF db_updated = node_updated AND db_client = p_client_uuid AND db_client_seq = (node_data->>'ClientSequence')::int THEN RAISE NOTICE '04, already recorded, %, %', db_client, db_client_seq; CONTINUE; END IF; /* Determine if the incoming node data is to go into history or replace the current node. */ IF db_updated > node_updated THEN RAISE NOTICE '02 DB newer, % > % (%))', db_updated, node_updated, node_uuid; /* Incoming node is going straight to history since it is older than the current node. */ INSERT INTO node_history( user_id, "uuid", parents, created, updated, "name", "content", markdown, "content_encrypted", client, client_sequence ) VALUES( p_user_id, node_uuid, (jsonb_populate_record(null::json_ancestor_array, node_data))."Ancestors", (node_data->>'Created')::timestamptz, (node_data->>'Updated')::timestamptz, (node_data->>'Name')::varchar, (node_data->>'Content')::text, (node_data->>'Markdown')::bool, '', /* content_encrypted */ p_client_uuid, (node_data->>'ClientSequence')::int ) ON CONFLICT (client, client_sequence) DO NOTHING; ELSE RAISE NOTICE '03 Client newer, % > % (%, %)', node_updated, db_updated, node_uuid, (node_data->>'ClientSequence'); /* Incoming node is newer and will replace the current node. * * The current node is copied to the node_history table and then modified in place * with the incoming data. */ INSERT INTO node_history( user_id, "uuid", parents, created, updated, "name", "content", markdown, "content_encrypted", client, client_sequence ) SELECT user_id, "uuid", ( WITH RECURSIVE nodes AS ( SELECT uuid, COALESCE(parent_uuid, '') AS parent_uuid, name, 0 AS depth FROM node WHERE uuid = node_uuid UNION SELECT n.uuid, COALESCE(n.parent_uuid, '') AS parent_uuid, n.name, nr.depth+1 AS depth FROM node n INNER JOIN nodes nr ON n.uuid = nr.parent_uuid ) SELECT ARRAY ( SELECT name FROM nodes ORDER BY depth DESC OFFSET 1 /* discard itself */ ) ), created, updated, name, content, markdown, content_encrypted, client, client_sequence FROM public."node" WHERE user_id = p_user_id AND uuid = node_uuid ON CONFLICT (client, client_sequence) DO NOTHING; /* Current node in database is updated with incoming data. */ UPDATE public."node" SET updated = (node_data->>'Updated')::timestamptz, updated_seq = nextval('node_updates'), name = (node_data->>'Name')::varchar, content = (node_data->>'Content')::text, markdown = (node_data->>'Markdown')::bool, client = p_client_uuid, client_sequence = (node_data->>'ClientSequence')::int WHERE user_id = p_user_id AND uuid = node_uuid; END IF; END LOOP; END $$;