Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Fix FK constraints for compressed chunks #6797

Merged
merged 1 commit into from
Apr 13, 2024

Commits on Apr 13, 2024

  1. Fix FK constraints for compressed chunks

    When foreign key support for compressed chunks was added we moved
    the FK constraint from the uncompressed chunk to the compressed chunk as
    part of compress_chunk and moved it back as part of decompress_chunk.
    With the addition of partially compressed chunks in 2.10.x this approach
    was no longer sufficient and the FK constraint needs to be present on
    both the uncompressed and the compressed chunk.
    
    While this patch will fix future compressed chunks a migration has to be
    run after upgrading timescaledb to migrate existing chunks affected by
    this.
    
    The following code will fix any affected hypertables:
    ```
    CREATE OR REPLACE FUNCTION pg_temp.constraint_columns(regclass, int2[]) RETURNS text[] AS
    $$
      SELECT array_agg(attname) FROM unnest($2) un(attnum) LEFT JOIN pg_attribute att ON att.attrelid=$1 AND att.attnum = un.attnum;
    $$ LANGUAGE SQL SET search_path TO pg_catalog, pg_temp;
    
    DO $$
    DECLARE
      ht_id int;
      ht regclass;
      chunk regclass;
      con_oid oid;
      con_frelid regclass;
      con_name text;
      con_columns text[];
      chunk_id int;
    
    BEGIN
    
      -- iterate over all hypertables that have foreign key constraints
      FOR ht_id, ht in
        SELECT
          ht.id,
          format('%I.%I',ht.schema_name,ht.table_name)::regclass
        FROM _timescaledb_catalog.hypertable ht
        WHERE
          EXISTS (
            SELECT FROM pg_constraint con
            WHERE
              con.contype='f' AND
              con.conrelid=format('%I.%I',ht.schema_name,ht.table_name)::regclass
          )
      LOOP
        RAISE NOTICE 'Hypertable % has foreign key constraint', ht;
    
        -- iterate over all foreign key constraints on the hypertable
        -- and check that they are present on every chunk
        FOR con_oid, con_frelid, con_name, con_columns IN
          SELECT con.oid, con.confrelid, con.conname, pg_temp.constraint_columns(con.conrelid,con.conkey)
          FROM pg_constraint con
          WHERE
            con.contype='f' AND
            con.conrelid=ht
        LOOP
          RAISE NOTICE 'Checking constraint % %', con_name, con_columns;
          -- check that the foreign key constraint is present on the chunk
    
          FOR chunk_id, chunk IN
            SELECT
              ch.id,
              format('%I.%I',ch.schema_name,ch.table_name)::regclass
            FROM _timescaledb_catalog.chunk ch
            WHERE
              ch.hypertable_id=ht_id
          LOOP
            RAISE NOTICE 'Checking chunk %', chunk;
            IF NOT EXISTS (
              SELECT FROM pg_constraint con
              WHERE
                con.contype='f' AND
                con.conrelid=chunk AND
                con.confrelid=con_frelid  AND
                pg_temp.constraint_columns(con.conrelid,con.conkey) = con_columns
            ) THEN
              RAISE WARNING 'Restoring constraint % on chunk %', con_name, chunk;
              PERFORM _timescaledb_functions.constraint_clone(con_oid, chunk);
              INSERT INTO _timescaledb_catalog.chunk_constraint(chunk_id, dimension_slice_id, constraint_name, hypertable_constraint_name) VALUES (chunk_id, NULL, con_name, con_name);
            END IF;
    
          END LOOP;
        END LOOP;
    
      END LOOP;
    
    END
    $$;
    
    DROP FUNCTION pg_temp.constraint_columns(regclass, int2[]);
    ```
    svenklemm committed Apr 13, 2024
    Configuration menu
    Copy the full SHA
    5586d8f View commit details
    Browse the repository at this point in the history