diff --git a/scripts-available/CDB_CartodbfyTable.sql b/scripts-available/CDB_CartodbfyTable.sql index 8f8af8a..ed267ce 100644 --- a/scripts-available/CDB_CartodbfyTable.sql +++ b/scripts-available/CDB_CartodbfyTable.sql @@ -142,6 +142,43 @@ BEGIN END IF; END LOOP; -- } + -- Try to copy data from new name if possible + IF new_name IS NOT NULL THEN + RAISE NOTICE 'Trying to recover data from % coumn', new_name; + BEGIN + -- Copy existing values to new field + sql := 'UPDATE ' || reloid::text || ' SET cartodb_id = ' + || new_name || '::int4'; + RAISE DEBUG 'Running %', sql; + EXECUTE sql; + + -- Find max value + sql := 'SELECT max(cartodb_id) FROM ' || reloid::text; + RAISE DEBUG 'Running %', sql; + EXECUTE sql INTO rec; + + -- Find sequence name + SELECT pg_catalog.pg_get_serial_sequence(reloid::text, 'cartodb_id') + AS seq INTO rec2; + + -- Reset sequence name + sql := 'ALTER SEQUENCE ' || rec2.seq::text + || ' RESTART WITH ' || rec.max + 1; + RAISE DEBUG 'Running %', sql; + EXECUTE sql; + + -- Drop old column (all went find if we got here) + sql := 'ALTER TABLE ' || reloid::text || ' DROP ' || new_name; + RAISE DEBUG 'Running %', sql; + EXECUTE sql; + + EXCEPTION + WHEN others THEN + RAISE NOTICE 'Could not initialize cartodb_id with existing values: % (%)', + SQLERRM, SQLSTATE; + END; + END IF; + -- We need created_at and updated_at FOR rec IN SELECT * FROM ( VALUES ('created_at'), ('updated_at') ) t(cname) LOOP --{ << column_setup >> diff --git a/test/CDB_CartodbfyTableTest.sql b/test/CDB_CartodbfyTableTest.sql index 0951126..ca843b8 100644 --- a/test/CDB_CartodbfyTableTest.sql +++ b/test/CDB_CartodbfyTableTest.sql @@ -178,6 +178,18 @@ SELECT CDB_CartodbfyTableCheck('t', 'text timestamps'); SELECT reftime-created_at, reftime-updated_at FROM t; DROP TABLE t; +-- table with existing cartodb_id field ot type text +CREATE TABLE t AS SELECT 10::text as cartodb_id; +SELECT CDB_CartodbfyTableCheck('t', 'text cartodb_id'); +select cartodb_id/2 FROM t; +DROP TABLE t; + +-- table with existing cartodb_id field ot type text not casting +CREATE TABLE t AS SELECT 'nan' as cartodb_id; +SELECT CDB_CartodbfyTableCheck('t', 'uncasting text cartodb_id'); +select cartodb_id,_cartodb_id0 FROM t; +DROP TABLE t; + -- TODO: table with existing custom-triggered the_geom DROP FUNCTION CDB_CartodbfyTableCheck(regclass, text); diff --git a/test/CDB_CartodbfyTableTest_expect b/test/CDB_CartodbfyTableTest_expect index d51a41e..7c58681 100644 --- a/test/CDB_CartodbfyTableTest_expect +++ b/test/CDB_CartodbfyTableTest_expect @@ -29,5 +29,13 @@ SELECT 1 text timestamps cartodbfied fine @ 0|@ 0 DROP TABLE +SELECT 1 +text cartodb_id cartodbfied fine +5 +DROP TABLE +SELECT 1 +uncasting text cartodb_id cartodbfied fine +1|nan +DROP TABLE DROP FUNCTION DROP FUNCTION