Workaround PostgreSQL bug possibly triggering infinite loops
Implements casting of existing system column values during cartodbfication using ALTER rather than UPDATE. It's faster for tables with many rows and works around a longstanding PostgreSQL bug. See http://www.postgresql.org/message-id/20140530143150.GA11051@localhost CDB-3059
This commit is contained in:
parent
cc9cbdb7a7
commit
ce20009fb2
1
NEWS
1
NEWS
@ -7,6 +7,7 @@ Bug fixes:
|
||||
- Ensure cartodb_id uses an associated sequence (#33)
|
||||
- Fully qualify call to cdb_disable_ddl_hooks from cdb_enable_ddl_hooks
|
||||
- Fully qualify call to CDB_UserDataSize from quota trigger
|
||||
- Fix potential infinite loop in CDB_CartodbfyTable
|
||||
|
||||
|
||||
0.1.0 - 2014-05-23
|
||||
|
@ -158,7 +158,11 @@ BEGIN
|
||||
RAISE NOTICE 'Trying to recover data from % column', new_name;
|
||||
BEGIN
|
||||
-- Copy existing values to new field
|
||||
sql := 'UPDATE ' || reloid::text || ' SET cartodb_id = '
|
||||
-- NOTE: using ALTER is a workaround to a PostgreSQL bug and
|
||||
-- is also known to be faster for tables with many rows
|
||||
-- See http://www.postgresql.org/message-id/20140530143150.GA11051@localhost
|
||||
sql := 'ALTER TABLE ' || reloid::text
|
||||
|| ' ALTER cartodb_id TYPE int USING '
|
||||
|| new_name || '::int4';
|
||||
RAISE DEBUG 'Running %', sql;
|
||||
EXECUTE sql;
|
||||
@ -273,7 +277,11 @@ cname, rec2.typname;
|
||||
RAISE NOTICE 'Trying to recover data from % coumn', new_name;
|
||||
BEGIN
|
||||
-- Copy existing values to new field
|
||||
sql := 'UPDATE ' || reloid::text || ' SET ' || rec.cname || ' = '
|
||||
-- NOTE: using ALTER is a workaround to a PostgreSQL bug and
|
||||
-- is also known to be faster for tables with many rows
|
||||
-- See http://www.postgresql.org/message-id/20140530143150.GA11051@localhost
|
||||
sql := 'ALTER TABLE ' || reloid::text || ' ALTER ' || rec.cname
|
||||
|| ' TYPE TIMESTAMPTZ USING '
|
||||
|| new_name || '::timestamptz';
|
||||
RAISE DEBUG 'Running %', sql;
|
||||
EXECUTE sql;
|
||||
|
@ -200,6 +200,22 @@ SELECT CDB_CartodbfyTableCheck('t', 'unsequenced cartodb_id');
|
||||
select cartodb_id FROM t;
|
||||
DROP TABLE t;
|
||||
|
||||
-- table with existing the_geom and created_at and containing null values
|
||||
-- Really, a test for surviving an longstanding PostgreSQL bug:
|
||||
-- http://www.postgresql.org/message-id/20140530143150.GA11051@localhost
|
||||
CREATE TABLE t (
|
||||
the_geom geometry(Geometry,4326),
|
||||
created_at timestamptz,
|
||||
updated_at timestamptz
|
||||
);
|
||||
COPY t (the_geom, created_at, updated_at) FROM stdin;
|
||||
0106000020E610000001000000010300000001000000050000009EB8244146435BC017B65E062AD343409EB8244146435BC0F51AF6E2708044400B99891683765AC0F51AF6E2708044400B99891683765AC017B65E062AD343409EB8244146435BC017B65E062AD34340 2012-06-06 21:59:08 2013-06-10 20:17:20
|
||||
0106000020E61000000100000001030000000100000005000000DA7763431A1A5CC0FBCEE869313C3A40DA7763431A1A5CC09C1B8F55BC494440F9F4A9C7993356C09C1B8F55BC494440F9F4A9C7993356C0FBCEE869313C3A40DA7763431A1A5CC0FBCEE869313C3A40 2012-06-06 21:59:08 2013-06-10 20:17:20
|
||||
\N \N \N
|
||||
\.
|
||||
SELECT CDB_CartodbfyTableCheck('t', 'null geom and timestamp values');
|
||||
DROP TABLE t;
|
||||
|
||||
-- TODO: table with existing custom-triggered the_geom
|
||||
|
||||
DROP FUNCTION CDB_CartodbfyTableCheck(regclass, text);
|
||||
|
@ -44,5 +44,8 @@ SELECT 1
|
||||
unsequenced cartodb_id cartodbfied fine
|
||||
1
|
||||
DROP TABLE
|
||||
CREATE TABLE
|
||||
null geom and timestamp values cartodbfied fine
|
||||
DROP TABLE
|
||||
DROP FUNCTION
|
||||
DROP FUNCTION
|
||||
|
Loading…
Reference in New Issue
Block a user