-- -- Copyright © 2016-2020 The Thingsboard Authors -- -- Licensed under the Apache License, Version 2.0 (the "License"); -- you may not use this file except in compliance with the License. -- You may obtain a copy of the License at -- -- http://www.apache.org/licenses/LICENSE-2.0 -- -- Unless required by applicable law or agreed to in writing, software -- distributed under the License is distributed on an "AS IS" BASIS, -- WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. -- See the License for the specific language governing permissions and -- limitations under the License. -- CREATE EXTENSION IF NOT EXISTS timescaledb CASCADE; CREATE TABLE IF NOT EXISTS ts_kv ( entity_id uuid NOT NULL, key int NOT NULL, ts bigint NOT NULL, bool_v boolean, str_v varchar(10000000), long_v bigint, dbl_v double precision, json_v json, CONSTRAINT ts_kv_pkey PRIMARY KEY (entity_id, key, ts) ); CREATE TABLE IF NOT EXISTS ts_kv_dictionary ( key varchar(255) NOT NULL, key_id serial UNIQUE, CONSTRAINT ts_key_id_pkey PRIMARY KEY (key) ); CREATE TABLE IF NOT EXISTS ts_kv_latest ( entity_id uuid NOT NULL, key int NOT NULL, ts bigint NOT NULL, bool_v boolean, str_v varchar(10000000), long_v bigint, dbl_v double precision, json_v json, CONSTRAINT ts_kv_latest_pkey PRIMARY KEY (entity_id, key) ); CREATE TABLE IF NOT EXISTS tb_schema_settings ( schema_version bigint NOT NULL, CONSTRAINT tb_schema_settings_pkey PRIMARY KEY (schema_version) ); INSERT INTO tb_schema_settings (schema_version) VALUES (2005000); CREATE OR REPLACE FUNCTION to_uuid(IN entity_id varchar, OUT uuid_id uuid) AS $$ BEGIN uuid_id := substring(entity_id, 8, 8) || '-' || substring(entity_id, 4, 4) || '-1' || substring(entity_id, 1, 3) || '-' || substring(entity_id, 16, 4) || '-' || substring(entity_id, 20, 12); END; $$ LANGUAGE plpgsql; CREATE OR REPLACE FUNCTION delete_device_records_from_ts_kv(tenant_id varchar, customer_id varchar, ttl bigint, OUT deleted bigint) AS $$ BEGIN EXECUTE format( 'WITH deleted AS (DELETE FROM ts_kv WHERE entity_id IN (SELECT to_uuid(device.id) as entity_id FROM device WHERE tenant_id = %L and customer_id = %L) AND ts < %L::bigint RETURNING *) SELECT count(*) FROM deleted', tenant_id, customer_id, ttl) into deleted; END; $$ LANGUAGE plpgsql; CREATE OR REPLACE FUNCTION delete_asset_records_from_ts_kv(tenant_id varchar, customer_id varchar, ttl bigint, OUT deleted bigint) AS $$ BEGIN EXECUTE format( 'WITH deleted AS (DELETE FROM ts_kv WHERE entity_id IN (SELECT to_uuid(asset.id) as entity_id FROM asset WHERE tenant_id = %L and customer_id = %L) AND ts < %L::bigint RETURNING *) SELECT count(*) FROM deleted', tenant_id, customer_id, ttl) into deleted; END; $$ LANGUAGE plpgsql; CREATE OR REPLACE FUNCTION delete_customer_records_from_ts_kv(tenant_id varchar, customer_id varchar, ttl bigint, OUT deleted bigint) AS $$ BEGIN EXECUTE format( 'WITH deleted AS (DELETE FROM ts_kv WHERE entity_id IN (SELECT to_uuid(customer.id) as entity_id FROM customer WHERE tenant_id = %L and id = %L) AND ts < %L::bigint RETURNING *) SELECT count(*) FROM deleted', tenant_id, customer_id, ttl) into deleted; END; $$ LANGUAGE plpgsql; CREATE OR REPLACE PROCEDURE cleanup_timeseries_by_ttl(IN null_uuid varchar(31), IN system_ttl bigint, INOUT deleted bigint) LANGUAGE plpgsql AS $$ DECLARE tenant_cursor CURSOR FOR select tenant.id as tenant_id from tenant; tenant_id_record varchar; customer_id_record varchar; tenant_ttl bigint; customer_ttl bigint; deleted_for_entities bigint; tenant_ttl_ts bigint; customer_ttl_ts bigint; BEGIN OPEN tenant_cursor; FETCH tenant_cursor INTO tenant_id_record; WHILE FOUND LOOP EXECUTE format( 'select attribute_kv.long_v from attribute_kv where attribute_kv.entity_id = %L and attribute_kv.attribute_key = %L', tenant_id_record, 'TTL') INTO tenant_ttl; if tenant_ttl IS NULL THEN tenant_ttl := system_ttl; END IF; IF tenant_ttl > 0 THEN tenant_ttl_ts := (EXTRACT(EPOCH FROM current_timestamp) * 1000 - tenant_ttl::bigint * 1000)::bigint; deleted_for_entities := delete_device_records_from_ts_kv(tenant_id_record, null_uuid, tenant_ttl_ts); deleted := deleted + deleted_for_entities; RAISE NOTICE '% telemetry removed for devices where tenant_id = %', deleted_for_entities, tenant_id_record; deleted_for_entities := delete_asset_records_from_ts_kv(tenant_id_record, null_uuid, tenant_ttl_ts); deleted := deleted + deleted_for_entities; RAISE NOTICE '% telemetry removed for assets where tenant_id = %', deleted_for_entities, tenant_id_record; END IF; FOR customer_id_record IN SELECT customer.id AS customer_id FROM customer WHERE customer.tenant_id = tenant_id_record LOOP EXECUTE format( 'select attribute_kv.long_v from attribute_kv where attribute_kv.entity_id = %L and attribute_kv.attribute_key = %L', customer_id_record, 'TTL') INTO customer_ttl; IF customer_ttl IS NULL THEN customer_ttl_ts := tenant_ttl_ts; ELSE IF customer_ttl > 0 THEN customer_ttl_ts := (EXTRACT(EPOCH FROM current_timestamp) * 1000 - customer_ttl::bigint * 1000)::bigint; END IF; END IF; IF customer_ttl_ts IS NOT NULL AND customer_ttl_ts > 0 THEN deleted_for_entities := delete_customer_records_from_ts_kv(tenant_id_record, customer_id_record, customer_ttl_ts); deleted := deleted + deleted_for_entities; RAISE NOTICE '% telemetry removed for customer with id = % where tenant_id = %', deleted_for_entities, customer_id_record, tenant_id_record; deleted_for_entities := delete_device_records_from_ts_kv(tenant_id_record, customer_id_record, customer_ttl_ts); deleted := deleted + deleted_for_entities; RAISE NOTICE '% telemetry removed for devices where tenant_id = % and customer_id = %', deleted_for_entities, tenant_id_record, customer_id_record; deleted_for_entities := delete_asset_records_from_ts_kv(tenant_id_record, customer_id_record, customer_ttl_ts); deleted := deleted + deleted_for_entities; RAISE NOTICE '% telemetry removed for assets where tenant_id = % and customer_id = %', deleted_for_entities, tenant_id_record, customer_id_record; END IF; END LOOP; FETCH tenant_cursor INTO tenant_id_record; END LOOP; END $$;