Skip to content

Commit

Permalink
Merge branch 'feat/simplify-schema-2'
Browse files Browse the repository at this point in the history
  • Loading branch information
bethesque committed Aug 9, 2018
2 parents e6bd19f + 485cc7f commit 0c70bef
Show file tree
Hide file tree
Showing 51 changed files with 570 additions and 391 deletions.
41 changes: 14 additions & 27 deletions DEVELOPER_DOCUMENTATION.md
Original file line number Diff line number Diff line change
Expand Up @@ -71,38 +71,25 @@ Domain classes are found in `lib/pact_broker/domain`. Many of these classes are

* `latest_tagged_pact_publications` - This view has the same columns as `all_pact_publications`, plus a `tag_name` column. It is used to return the pact for the latest tagged version of a consumer.

* `latest_verifications` - The most recent verification for each pact version.
* `latest_verifications_for_pact_versions` - The most recent verification for each pact version.

* `matrix` - The matrix of every pact publication and verification. Includes every pact revision (eg. publishing to the same consumer version twice, or using PATCH) and every verification (including 'overwritten' ones. eg. when the same provider build runs twice.)

* `latest_matrix_for_consumer_version_and_provider_version` - This view is a subset of, and has the same columns as, the `matrix`. It removes 'overwritten' pacts and verifications from the matrix (ie. only show latest pact revision for each consumer version and latest verification for each provider version)

### Materialized Views

We can't use proper materialized views because we have to support MySQL :|

So as a hacky solution, there are two tables which act as materialized views to speed up the performance of the matrix and index queries. These tables are updated after any resource is published with a `consumer_name`, `provider_name` or `pacticipant_name` in the URL (see lib/pact_broker/api/resources/base_resource.rb#finish_request).

* `materialized_matrix` table - is populated from the `matrix` view.

* `materialized_head_matrix` table - is populated from `head_matrix` view, and is based on `materialized_matrix`.

### Dependencies

materialized_head_matrix table (is populated from...)
= head_matrix view
-> latest_matrix_for_consumer_version_and_provider_version view
-> materialized_matrix table (is populated from...)
= matrix view
-> verifications table
-> versions table
-> all_pact_publications view
-> pact_versions table
-> pact_publications table
-> pacticipants table
-> versions table
-> latest_verification_id_for_consumer_version_and_provider_version view
-> latest_pact_publication_revision_numbers view
```
= head_matrix view
-> latest_pact_publications view
-> latest_pact_publications_by_consumer_versions view
-> latest_pact_publication_ids_by_consumer_versions
-> all_pact_publications
-> versions, pacticipants, pact_publications, pact_versions
-> latest_verifications_for_pact_versions
-> latest_verification_ids_for_pact_versions
-> versions
-> latest_tagged_pact_consumer_version_orders
-> latest_pact_publications_by_consumer_versions
```

### Useful to know stuff

Expand Down
10 changes: 10 additions & 0 deletions config/database.yml
Original file line number Diff line number Diff line change
Expand Up @@ -11,6 +11,11 @@ test:
postgres:
<<: *default
adapter: postgres
docker_postgres:
<<: *default
adapter: postgres
host: "127.0.0.1"
port: "5433"
mysql:
<<: *default
adapter: mysql2
Expand All @@ -22,6 +27,11 @@ development:
postgres:
<<: *default
adapter: postgres
docker_postgres:
<<: *default
adapter: postgres
host: "127.0.0.1"
port: "5433"
mysql:
<<: *default
adapter: mysql2
Expand Down
3 changes: 3 additions & 0 deletions db/ddl_statements.rb
Original file line number Diff line number Diff line change
@@ -0,0 +1,3 @@
Dir.glob(File.expand_path(File.join(__FILE__, "..", "ddl_statements", "*.rb"))).sort.each do | path |
require path
end
31 changes: 31 additions & 0 deletions db/ddl_statements/head_matrix_v001.rb
Original file line number Diff line number Diff line change
@@ -0,0 +1,31 @@
HEAD_MATRIX_V1 = "
select
p.consumer_id, p.consumer_name, p.consumer_version_id, p.consumer_version_number, p.consumer_version_order,
p.id as pact_publication_id, p.pact_version_id, p.pact_version_sha, p.revision_number as pact_revision_number,
p.created_at as pact_created_at,
p.provider_id, p.provider_name, lv.provider_version_id, lv.provider_version_number, lv.provider_version_order,
lv.id as verification_id, lv.success, lv.number as verification_number, lv.execution_date as verification_executed_at,
lv.build_url as verification_build_url,
null as consumer_version_tag_name
from latest_pact_publications p
left outer join latest_verifications lv
on p.pact_version_id = lv.pact_version_id
union all
select
p.consumer_id, p.consumer_name, p.consumer_version_id, p.consumer_version_number, p.consumer_version_order,
p.id as pact_publication_id, p.pact_version_id, p.pact_version_sha, p.revision_number as pact_revision_number,
p.created_at as pact_created_at,
p.provider_id, p.provider_name, lv.provider_version_id, lv.provider_version_number, lv.provider_version_order,
lv.id as verification_id, lv.success, lv.number as verification_number, lv.execution_date as verification_executed_at,
lv.build_url as verification_build_url,
lt.tag_name as consumer_version_tag_name
from latest_tagged_pact_consumer_version_orders lt
inner join latest_pact_publications_by_consumer_versions p
on lt.consumer_id = p.consumer_id
and lt.provider_id = p.provider_id
and lt.latest_consumer_version_order = p.consumer_version_order
left outer join latest_verifications lv
on p.pact_version_id = lv.pact_version_id
"
31 changes: 31 additions & 0 deletions db/ddl_statements/head_matrix_v002.rb
Original file line number Diff line number Diff line change
@@ -0,0 +1,31 @@
HEAD_MATRIX_V2 = "
select
p.consumer_id, p.consumer_name, p.consumer_version_id, p.consumer_version_number, p.consumer_version_order,
p.id as pact_publication_id, p.pact_version_id, p.pact_version_sha, p.revision_number as pact_revision_number,
p.created_at as pact_created_at,
p.provider_id, p.provider_name, lv.provider_version_id, lv.provider_version_number, lv.provider_version_order,
lv.id as verification_id, lv.success, lv.number as verification_number, lv.execution_date as verification_executed_at,
lv.build_url as verification_build_url,
null as consumer_version_tag_name
from latest_pact_publications p
left outer join latest_verifications_for_pact_versions lv
on p.pact_version_id = lv.pact_version_id
union all
select
p.consumer_id, p.consumer_name, p.consumer_version_id, p.consumer_version_number, p.consumer_version_order,
p.id as pact_publication_id, p.pact_version_id, p.pact_version_sha, p.revision_number as pact_revision_number,
p.created_at as pact_created_at,
p.provider_id, p.provider_name, lv.provider_version_id, lv.provider_version_number, lv.provider_version_order,
lv.id as verification_id, lv.success, lv.number as verification_number, lv.execution_date as verification_executed_at,
lv.build_url as verification_build_url,
lt.tag_name as consumer_version_tag_name
from latest_tagged_pact_consumer_version_orders lt
inner join latest_pact_publications_by_consumer_versions p
on lt.consumer_id = p.consumer_id
and lt.provider_id = p.provider_id
and lt.latest_consumer_version_order = p.consumer_version_order
left outer join latest_verifications_for_pact_versions lv
on p.pact_version_id = lv.pact_version_id
"
Original file line number Diff line number Diff line change
@@ -0,0 +1,4 @@
LATEST_VERIFICATION_IDS_FOR_PACT_VERSIONS_V1 =
"select pact_version_id, MAX(verification_id) latest_verification_id
FROM latest_verification_id_for_pact_version_and_provider_version
GROUP BY pact_version_id"
5 changes: 4 additions & 1 deletion db/migrations/000028_create_all_pact_publications.rb
Original file line number Diff line number Diff line change
Expand Up @@ -21,7 +21,8 @@
group by provider_id, consumer_id, consumer_version_order"
)

# Latest pact_publication details for each consumer version
# Latest pact_publication (revision) for each provider/consumer version
# updated in 20180519_recreate_views.rb
create_view(:latest_pact_publications_by_consumer_versions,
"select app.*
from all_pact_publications app
Expand All @@ -33,6 +34,8 @@
)


# updated in 20180519_recreate_views.rb
# This view tells us the latest consumer version with a pact for a consumer/provider pair
create_or_replace_view(:latest_pact_consumer_version_orders,
"select provider_id, consumer_id, max(consumer_version_order) as latest_consumer_version_order
from all_pact_publications
Expand Down
39 changes: 5 additions & 34 deletions db/migrations/20180311_optimise_head_matrix.rb
Original file line number Diff line number Diff line change
@@ -1,4 +1,5 @@
require_relative 'migration_helper'
require_relative '../ddl_statements'

Sequel.migration do
up do
Expand All @@ -16,7 +17,9 @@
)

# Add provider_version_order to original definition
# The most recent verification for each pact version
# The most recent verification for each pact_version
# provider_version column is DEPRECATED, use provider_version_number
# Think this can be replaced by latest_verification_id_for_pact_version_and_provider_version?
v = :verifications
create_or_replace_view(:latest_verifications,
from(v)
Expand Down Expand Up @@ -44,38 +47,6 @@
)


create_or_replace_view(:head_matrix,
"
select
p.consumer_id, p.consumer_name, p.consumer_version_id, p.consumer_version_number, p.consumer_version_order,
p.id as pact_publication_id, p.pact_version_id, p.pact_version_sha, p.revision_number as pact_revision_number,
p.created_at as pact_created_at,
p.provider_id, p.provider_name, lv.provider_version_id, lv.provider_version_number, lv.provider_version_order,
lv.id as verification_id, lv.success, lv.number as verification_number, lv.execution_date as verification_executed_at,
lv.build_url as verification_build_url,
null as consumer_version_tag_name
from latest_pact_publications p
left outer join latest_verifications lv
on p.pact_version_id = lv.pact_version_id
union all
select
p.consumer_id, p.consumer_name, p.consumer_version_id, p.consumer_version_number, p.consumer_version_order,
p.id as pact_publication_id, p.pact_version_id, p.pact_version_sha, p.revision_number as pact_revision_number,
p.created_at as pact_created_at,
p.provider_id, p.provider_name, lv.provider_version_id, lv.provider_version_number, lv.provider_version_order,
lv.id as verification_id, lv.success, lv.number as verification_number, lv.execution_date as verification_executed_at,
lv.build_url as verification_build_url,
lt.tag_name as consumer_version_tag_name
from latest_tagged_pact_consumer_version_orders lt
inner join latest_pact_publications_by_consumer_versions p
on lt.consumer_id = p.consumer_id
and lt.provider_id = p.provider_id
and lt.latest_consumer_version_order = p.consumer_version_order
left outer join latest_verifications lv
on p.pact_version_id = lv.pact_version_id
"
)
create_or_replace_view(:head_matrix, HEAD_MATRIX_V1)
end
end
Original file line number Diff line number Diff line change
@@ -1,6 +1,8 @@
Sequel.migration do
up do
# The latest verification id for each consumer version tag
# This is not the latest verification for the latest pact with a given tag,
# this is the latest verification for any pact with the tag
create_view(:latest_verification_ids_for_consumer_version_tags,
"select
pv.pacticipant_id as provider_id,
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -4,4 +4,8 @@
up do
PactBroker::DB::DataMigrations::SetConsumerIdsForPactPublications.call(self)
end

down do
from(:pact_publications).update(consumer_id: nil)
end
end
Original file line number Diff line number Diff line change
Expand Up @@ -7,6 +7,7 @@
# you can't delete a single pact revision through the API - all the revisions
# for a pact are deleted together when you delete the pact resource for that
# consumer version, and when that happens, this row will cascade delete.

create_table(:latest_pact_publication_ids_for_consumer_versions, charset: 'utf8') do
foreign_key :consumer_id, :pacticipants, null: false, on_delete: :cascade # redundant, but speeds up queries by removing need for extra join
foreign_key :consumer_version_id, :versions, null: false, on_delete: :cascade
Expand Down
11 changes: 11 additions & 0 deletions db/migrations/20180721_migrate_latest_pact_publication_ids.rb
Original file line number Diff line number Diff line change
@@ -0,0 +1,11 @@
Sequel.migration do
up do
# The danger with this migration is that a pact publication created by an old node will be lost
rows = from(:latest_pact_publications_by_consumer_versions).select(:consumer_id, :consumer_version_id, :provider_id, :id, :pact_version_id)
from(:latest_pact_publication_ids_for_consumer_versions).insert(rows)
end

down do
from(:latest_pact_publication_ids_for_consumer_versions).delete
end
end
43 changes: 43 additions & 0 deletions db/migrations/20180722_recreate_views.rb
Original file line number Diff line number Diff line change
@@ -0,0 +1,43 @@
Sequel.migration do
up do
# Latest pact_publication details for each provider/consumer version
create_or_replace_view(:latest_pact_publications_by_consumer_versions,
"select app.*
from latest_pact_publication_ids_for_consumer_versions lpp
inner join all_pact_publications app
on lpp.consumer_version_id = app.consumer_version_id
and lpp.pact_publication_id = app.id
and lpp.provider_id = app.provider_id"
)

# Latest consumer version order for consumer/provider
# Recreate latest_pact_publication_ids_for_consumer_versions view
lpp = :latest_pact_publication_ids_for_consumer_versions
latest_pact_consumer_version_orders = from(lpp).select_group(
Sequel[lpp][:provider_id],
Sequel[:cv][:pacticipant_id].as(:consumer_id))
.select_append{ max(order).as(latest_consumer_version_order) }
.join(:versions, { Sequel[lpp][:consumer_version_id] => Sequel[:cv][:id] }, { table_alias: :cv })

create_or_replace_view(:latest_pact_consumer_version_orders, latest_pact_consumer_version_orders)
end

down do
# Latest pact_publication details for each provider/consumer version
create_or_replace_view(:latest_pact_publications_by_consumer_versions,
"select app.*
from all_pact_publications app
inner join latest_pact_publication_revision_numbers lr
on app.consumer_id = lr.consumer_id
and app.provider_id = lr.provider_id
and app.consumer_version_order = lr.consumer_version_order
and app.revision_number = lr.latest_revision_number"
)

create_or_replace_view(:latest_pact_consumer_version_orders,
"select provider_id, consumer_id, max(consumer_version_order) as latest_consumer_version_order
from all_pact_publications
group by provider_id, consumer_id"
)
end
end
23 changes: 23 additions & 0 deletions db/migrations/20180723_create_latest_verification_ids.rb
Original file line number Diff line number Diff line change
@@ -0,0 +1,23 @@
Sequel.migration do
up do
# Latest verification_id for each pact version/provider version.
# Keeping track of this in a table rather than having to calculate the
# latest revision speeds queries up.
# There is no way to delete an individual verification result yet, but when there
# is, we'll need to re-calculate the latest.
create_table(:latest_verification_id_for_pact_version_and_provider_version, charset: 'utf8') do
foreign_key :consumer_id, :pacticipants, null: false, on_delete: :cascade, foreign_key_constraint_name: 'latest_v_id_for_pv_and_pv_consumer_id_fk' # not required, but useful to avoid extra joins
foreign_key :pact_version_id, :pact_versions, null: false, on_delete: :cascade, foreign_key_constraint_name: 'latest_v_id_for_pv_and_pv_pact_version_id_fk'
foreign_key :provider_id, :pacticipants, null: false, on_delete: :cascade, foreign_key_constraint_name: 'latest_v_id_for_pv_and_pv_provider_id_fk' # not required, but useful to avoid extra joins
foreign_key :provider_version_id, :versions, null: false, on_delete: :cascade, foreign_key_constraint_name: 'latest_v_id_for_pv_and_pv_provider_version_id_fk'
foreign_key :verification_id, :verifications, null: false, on_delete: :cascade, foreign_key_constraint_name: 'latest_v_id_for_pv_and_pv_verification_id_fk'
index [:verification_id], unique: true, name: "latest_v_id_for_pv_and_pv_v_id_unq"
index [:pact_version_id, :provider_version_id], unique: true, name: "latest_v_id_for_pv_and_pv_pv_id_pv_id_unq"
index [:pact_version_id, :verification_id], name: "latest_v_id_for_pv_and_pv_pv_id_v_id"
end
end

down do
drop_table(:latest_verification_id_for_pact_version_and_provider_version)
end
end
18 changes: 18 additions & 0 deletions db/migrations/20180724_migrate_latest_verification_ids.rb
Original file line number Diff line number Diff line change
@@ -0,0 +1,18 @@
Sequel.migration do
up do
# consumer_id and provider_id are redundant by avoid making extra joins when creating views
rows = from(:verifications).select_group(
Sequel[:verifications][:consumer_id],
Sequel[:verifications][:pact_version_id],
Sequel[:verifications][:provider_id],
Sequel[:verifications][:provider_version_id])
.select_append{ max(verifications[id]).as(verification_id) }

# The danger with this migration is that a verification created by an old node will be lost
from(:latest_verification_id_for_pact_version_and_provider_version).insert(rows)
end

down do
from(:latest_verification_id_for_pact_version_and_provider_version).delete
end
end
29 changes: 29 additions & 0 deletions db/migrations/20180726_recreate_views.rb
Original file line number Diff line number Diff line change
@@ -0,0 +1,29 @@
Sequel.migration do
up do
# joining with latest_pact_publication_revision_numbers gets rid of the overwritten
# pact revisions, and the max(verification_id) gets rid of the overwritten
# verifications
create_or_replace_view(:latest_verification_id_for_consumer_version_and_provider_version,
"select pp.consumer_version_id, lv.provider_version_id, lv.verification_id as latest_verification_id
from latest_pact_publication_ids_for_consumer_versions lpp
inner join pact_publications pp
on pp.id = lpp.pact_publication_id
left outer join latest_verification_id_for_pact_version_and_provider_version lv
on lv.pact_version_id = pp.pact_version_id"
)
end

down do
create_or_replace_view(:latest_verification_id_for_consumer_version_and_provider_version,
"select consumer_version_id, provider_version_id, max(verification_id) as latest_verification_id
from matrix
inner join latest_pact_publication_revision_numbers lr
on matrix.consumer_id = lr.consumer_id
and matrix.provider_id = lr.provider_id
and matrix.consumer_version_order = lr.consumer_version_order
and matrix.pact_revision_number = lr.latest_revision_number
group by consumer_version_id, provider_version_id"
)

end
end
Loading

0 comments on commit 0c70bef

Please sign in to comment.