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

Product Logging: Add sql scripts used for creating views in db #1194

Merged
merged 5 commits into from
Nov 4, 2024
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
12 changes: 12 additions & 0 deletions dcpy/migrations/2024010100_source_data__metadata_logging.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,12 @@
Create SCHEMA source_data;

CREATE TABLE source_data.metadata_logging (
name text NULL,
version text NULL,
timestamp timestamp NULL,
runner text NULL,
event_source text NULL
);

CREATE INDEX source_data_metadata_logging_name_idx ON source_data.metadata_logging USING btree (name, timestamp);
CREATE INDEX source_data_metadata_logging_timestamp_idx ON source_data.metadata_logging USING btree (timestamp);
Original file line number Diff line number Diff line change
Expand Up @@ -4,6 +4,8 @@ The table is used to track the lifecycle of data products,
from building to publishing, and is part of the de-qaqc database.
*/

CREATE SCHEMA product_data;

CREATE TABLE product_data.event_logging (
product VARCHAR(50) NOT NULL,
version VARCHAR(20) NOT NULL,
Expand Down
40 changes: 40 additions & 0 deletions dcpy/migrations/2024091020_product_data__latest_version_status.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,40 @@
/*
View: latest_version_status

This view selects the latest event for each product version
from the event_logging table, excluding 'db-template'.
It ranks events by priority ('publish', 'promote_to_draft', 'build')
and timestamp, returning the top-ranked event.
*/

CREATE VIEW product_data.latest_version_status AS (
WITH exclude_template AS (
SELECT *
FROM product_data.event_logging
WHERE product <> 'db-template'
),
ranked_events AS (
SELECT *,
ROW_NUMBER() OVER (
PARTITION BY product, version
ORDER BY
CASE
WHEN event IN ('publish', 'promote_to_draft') THEN 1
WHEN event = 'build' THEN 2
END,
timestamp DESC
) AS rank
FROM exclude_template
)
SELECT
product,
version,
event,
path,
old_path,
runner_type,
runner,
timestamp
FROM ranked_events
WHERE rank = 1
);
Original file line number Diff line number Diff line change
@@ -0,0 +1,51 @@
/*
View: product_version_lifecycle

This query aggregates information from the event logging table per product + version.
It returns only product versions that have both publish and draft events,
including the count of published and draft records, the earliest draft
timestamp, the latest publish timestamp, and the difference in days
between the two timestamps.
*/

CREATE VIEW product_data.product_version_lifecycle AS (
WITH latest_publish AS (
SELECT
product,
version,
COUNT(*) AS publish_count,
MAX(timestamp) AS latest_publish_timestamp
FROM product_data.event_logging
WHERE product <> 'db-template'
AND event = 'publish'
GROUP BY
product,
version
),
earliest_draft AS (
SELECT
product,
version,
COUNT(*) AS draft_count,
MIN(timestamp) AS earliest_draft_timestamp
FROM product_data.event_logging
WHERE product <> 'db-template'
AND event = 'promote_to_draft'
GROUP BY
product,
version
)
SELECT
published.product,
published.version,
published.publish_count,
draft.draft_count,
draft.earliest_draft_timestamp,
published.latest_publish_timestamp,
DATE_PART('day', published.latest_publish_timestamp - draft.earliest_draft_timestamp) AS total_days
FROM latest_publish AS published
INNER JOIN earliest_draft AS draft
ON published.product = draft.product
AND published.version = draft.version
)
);
11 changes: 11 additions & 0 deletions dcpy/migrations/Readme.md
Copy link
Contributor

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

@sf-dcp I think we should probably put the migrations in a folder called dcpy/migrations/database/ and have the README up one level in dcpy/migrations/README.md to avoid mixing these files.

Original file line number Diff line number Diff line change
@@ -0,0 +1,11 @@
# Migrations Directory

This directory contains SQL migration files used to create database schemas and tables. Each SQL file follows a strict naming convention to ensure orderly migration execution.

## File Naming Convention

Each migration file is named in the following format: `YYYYMMDDHH_{schema}__{table/view}.sql`.

## Usage

Run the SQL files in chronological order by timestamp to create or update database as required.
Loading