Commit 212e8ab4 authored by Robert May's avatar Robert May

Merge branch 'stomlinson/foreign-keys-view' into 'master'

Add a database view for postgres foreign keys

See merge request gitlab-org/gitlab!66473
parents fa94c4a2 44de0385
# frozen_string_literal: true
class AddForeignKeysView < ActiveRecord::Migration[6.1]
def up
execute(<<~SQL)
CREATE OR REPLACE VIEW postgres_foreign_keys AS
SELECT
pg_constraint.oid AS oid,
pg_constraint.conname AS name,
constrained_namespace.nspname::text || '.'::text || constrained_table.relname::text AS constrained_table_identifier,
referenced_namespace.nspname::text || '.'::text || referenced_table.relname::text AS referenced_table_identifier
FROM pg_constraint
INNER JOIN pg_class constrained_table ON constrained_table.oid = pg_constraint.conrelid
INNER JOIN pg_class referenced_table ON referenced_table.oid = pg_constraint.confrelid
INNER JOIN pg_namespace constrained_namespace ON constrained_table.relnamespace = constrained_namespace.oid
INNER JOIN pg_namespace referenced_namespace ON referenced_table.relnamespace = referenced_namespace.oid
WHERE contype = 'f';
SQL
end
def down
execute(<<~SQL)
DROP VIEW IF EXISTS postgres_foreign_keys
SQL
end
end
5e088e5109b50d8f4fadd37a0382d7dc4ce856a851ec2b97f8d5d868c3cb19fd
\ No newline at end of file
......@@ -16519,6 +16519,18 @@ CREATE SEQUENCE pool_repositories_id_seq
ALTER SEQUENCE pool_repositories_id_seq OWNED BY pool_repositories.id;
CREATE VIEW postgres_foreign_keys AS
SELECT pg_constraint.oid,
pg_constraint.conname AS name,
(((constrained_namespace.nspname)::text || '.'::text) || (constrained_table.relname)::text) AS constrained_table_identifier,
(((referenced_namespace.nspname)::text || '.'::text) || (referenced_table.relname)::text) AS referenced_table_identifier
FROM ((((pg_constraint
JOIN pg_class constrained_table ON ((constrained_table.oid = pg_constraint.conrelid)))
JOIN pg_class referenced_table ON ((referenced_table.oid = pg_constraint.confrelid)))
JOIN pg_namespace constrained_namespace ON ((constrained_table.relnamespace = constrained_namespace.oid)))
JOIN pg_namespace referenced_namespace ON ((referenced_table.relnamespace = referenced_namespace.oid)))
WHERE (pg_constraint.contype = 'f'::"char");
CREATE VIEW postgres_index_bloat_estimates AS
SELECT (((relation_stats.nspname)::text || '.'::text) || (relation_stats.idxname)::text) AS identifier,
(
# frozen_string_literal: true
module Gitlab
module Database
class PostgresForeignKey < ApplicationRecord
self.primary_key = :oid
scope :by_referenced_table_identifier, ->(identifier) do
raise ArgumentError, "Referenced table name is not fully qualified with a schema: #{identifier}" unless identifier =~ /^\w+\.\w+$/
where(referenced_table_identifier: identifier)
end
end
end
end
# frozen_string_literal: true
require 'spec_helper'
RSpec.describe Gitlab::Database::PostgresForeignKey, type: :model do
# PostgresForeignKey does not `behaves_like 'a postgres model'` because it does not correspond 1-1 with a single entry
# in pg_class
before do
ActiveRecord::Base.connection.execute(<<~SQL)
CREATE TABLE public.referenced_table (
id bigserial primary key not null
);
CREATE TABLE public.other_referenced_table (
id bigserial primary key not null
);
CREATE TABLE public.constrained_table (
id bigserial primary key not null,
referenced_table_id bigint not null,
other_referenced_table_id bigint not null,
CONSTRAINT fk_constrained_to_referenced FOREIGN KEY(referenced_table_id) REFERENCES referenced_table(id),
CONSTRAINT fk_constrained_to_other_referenced FOREIGN KEY(other_referenced_table_id)
REFERENCES other_referenced_table(id)
);
SQL
end
describe '#by_referenced_table_identifier' do
it 'throws an error when the identifier name is not fully qualified' do
expect { described_class.by_referenced_table_identifier('referenced_table') }.to raise_error(ArgumentError, /not fully qualified/)
end
it 'finds the foreign keys for the referenced table' do
expected = described_class.find_by!(name: 'fk_constrained_to_referenced')
expect(described_class.by_referenced_table_identifier('public.referenced_table')).to contain_exactly(expected)
end
end
end
Markdown is supported
0%
or
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment