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

feat(sqlmesh): atlas-defined collections #3208

Open
wants to merge 10 commits into
base: main
Choose a base branch
from
1 change: 1 addition & 0 deletions .gitignore
Original file line number Diff line number Diff line change
Expand Up @@ -38,6 +38,7 @@ data/
*.log
logs/
coverage.json
dev-tests/

# typescript
*.tsbuildinfo
Expand Down
Original file line number Diff line number Diff line change
@@ -1,7 +1,8 @@
MODEL (
name oso.int_artifacts_by_project_in_op_atlas,
kind FULL,
dialect trino
dialect trino,
description "Unifies all artifacts from OP Atlas, including handling cases where contracts come in via OSO"
);

WITH all_websites AS (
Expand All @@ -14,7 +15,8 @@ WITH all_websites AS (
artifact_url,
artifact_type
FROM oso.stg_op_atlas_project_website AS sites
), all_farcaster AS (
),
all_farcaster AS (
SELECT
project_id,
artifact_source_id,
Expand All @@ -24,7 +26,8 @@ WITH all_websites AS (
artifact_url,
artifact_type
FROM oso.stg_op_atlas_project_farcaster AS farcaster
), all_twitter AS (
),
all_twitter AS (
SELECT
project_id,
artifact_source_id,
Expand All @@ -34,17 +37,27 @@ WITH all_websites AS (
artifact_url,
artifact_type
FROM oso.stg_op_atlas_project_twitter AS twitter
), all_repository AS (
),
all_repository AS (
SELECT
project_id,
artifact_source_id,
artifact_source,
artifact_namespace,
artifact_name,
artifact_url,
artifact_type
FROM oso.stg_op_atlas_project_repository
), all_contracts AS (
ar.project_id,
(CASE
WHEN ossd_repos.artifact_source_id IS NOT NULL
THEN ossd_repos.artifact_source_id
ELSE CONCAT(ar.artifact_namespace, '/', ar.artifact_name)
END) AS artifact_source_id,
ar.artifact_source,
ar.artifact_namespace,
ar.artifact_name,
ar.artifact_url,
ar.artifact_type
FROM oso.stg_op_atlas_project_repository AS ar
LEFT OUTER JOIN oso.int_artifacts_by_project_in_ossd AS ossd_repos
ON ar.artifact_namespace = ossd_repos.artifact_namespace
AND ar.artifact_name = ossd_repos.artifact_name
AND ossd_repos.artifact_source = 'GITHUB'
),
all_contracts AS (
SELECT
project_id,
artifact_source_id,
Expand All @@ -54,7 +67,8 @@ WITH all_websites AS (
artifact_url,
artifact_type
FROM oso.stg_op_atlas_project_contract
), all_deployers AS (
),
all_deployers AS (
SELECT DISTINCT
project_id,
artifact_source_id,
Expand All @@ -64,7 +78,8 @@ WITH all_websites AS (
artifact_url,
artifact_type
FROM oso.stg_op_atlas_project_deployer
), all_defillama AS (
),
all_defillama AS (
SELECT
project_id,
artifact_source_id,
Expand All @@ -74,7 +89,8 @@ WITH all_websites AS (
artifact_url,
artifact_type
FROM oso.stg_op_atlas_project_defillama
), all_artifacts AS (
),
all_artifacts AS (
SELECT
*
FROM all_websites
Expand Down Expand Up @@ -102,7 +118,48 @@ WITH all_websites AS (
SELECT
*
FROM all_defillama
), all_normalized_artifacts AS (
),
-- Handle case where contracts come in via OSO
oso_linked_projects AS (
SELECT
op_atlas.project_id AS op_atlas_project_id,
ossd.project_id AS ossd_project_id,
op_atlas.open_source_observer_slug
FROM oso.stg_op_atlas_project AS op_atlas
JOIN oso.int_projects AS ossd
ON ossd.project_source = 'OSS_DIRECTORY'
AND ossd.project_name = op_atlas.open_source_observer_slug
WHERE op_atlas.open_source_observer_slug IS NOT NULL
),
-- Get artifacts from OSSD for the linked projects
oso_artifacts AS (
SELECT
linked.op_atlas_project_id AS project_id,
ossd_artifacts.artifact_source_id,
ossd_artifacts.artifact_source,
ossd_artifacts.artifact_namespace,
ossd_artifacts.artifact_name,
ossd_artifacts.artifact_url,
ossd_artifacts.artifact_type
FROM oso_linked_projects AS linked
JOIN oso.int_artifacts_by_project_in_ossd AS ossd_artifacts
ON linked.ossd_project_id = ossd_artifacts.project_id
WHERE ossd_artifacts.artifact_type IN ('CONTRACT', 'DEPLOYER')
AND NOT EXISTS (
SELECT 1
FROM all_artifacts AS op_atlas_artifacts
WHERE
op_atlas_artifacts.project_id = linked.op_atlas_project_id
AND UPPER(op_atlas_artifacts.artifact_source) = ossd_artifacts.artifact_source
AND LOWER(op_atlas_artifacts.artifact_name) = ossd_artifacts.artifact_name
)
),
all_combined_artifacts AS (
SELECT * FROM all_artifacts
UNION ALL
SELECT * FROM oso_artifacts
),
all_normalized_artifacts AS (
SELECT DISTINCT
project_id,
LOWER(artifact_source_id) AS artifact_source_id,
Expand All @@ -111,15 +168,18 @@ WITH all_websites AS (
LOWER(artifact_name) AS artifact_name,
LOWER(artifact_url) AS artifact_url,
UPPER(artifact_type) AS artifact_type
FROM all_artifacts
FROM all_combined_artifacts
)
SELECT
project_id,
@oso_id(artifact_source, artifact_namespace, artifact_name) AS artifact_id,
CASE
WHEN artifact_source = 'GITHUB' THEN @oso_id(artifact_source, artifact_source_id)
ELSE @oso_id(artifact_source, artifact_namespace, artifact_name)
END AS artifact_id,
artifact_source_id,
artifact_source,
artifact_namespace,
artifact_name,
artifact_url,
artifact_type
FROM all_normalized_artifacts
FROM all_normalized_artifacts
Original file line number Diff line number Diff line change
Expand Up @@ -11,4 +11,13 @@ SELECT
collections.collection_name,
collections.display_name,
collections.description
FROM oso.stg_ossd__current_collections AS collections
FROM oso.stg_ossd__current_collections AS collections
UNION ALL
SELECT DISTINCT
atlas_collections.collection_id,
atlas_collections.collection_source,
atlas_collections.collection_namespace,
atlas_collections.collection_name,
atlas_collections.collection_display_name AS display_name,
NULL::TEXT AS description
FROM oso.int_projects_by_collection_in_op_atlas AS atlas_collections
Original file line number Diff line number Diff line change
Expand Up @@ -5,15 +5,23 @@ MODEL (
);

SELECT
stg_ossd__current_collections.collection_id,
stg_ossd__current_collections.collection_source,
stg_ossd__current_collections.collection_namespace,
stg_ossd__current_collections.collection_name,
stg_ossd__current_projects.project_id,
stg_ossd__current_projects.project_source,
stg_ossd__current_projects.project_namespace,
stg_ossd__current_projects.project_name
FROM oso.stg_ossd__current_collections AS stg_ossd__current_collections
CROSS JOIN UNNEST(stg_ossd__current_collections.projects) AS cc(project_name)
INNER JOIN oso.stg_ossd__current_projects AS stg_ossd__current_projects
ON stg_ossd__current_projects.project_name = cc.project_name
collection_id,
collection_source,
collection_namespace,
collection_name,
project_id,
project_source,
project_namespace,
project_name
FROM oso.int_projects_by_collection_in_ossd
UNION ALL
SELECT
collection_id,
collection_source,
collection_namespace,
collection_name,
project_id,
project_source,
project_namespace,
project_name
FROM oso.int_projects_by_collection_in_op_atlas
Original file line number Diff line number Diff line change
@@ -0,0 +1,53 @@
MODEL (
name oso.int_projects_by_collection_in_op_atlas,
description "Many-to-many mapping of projects to Retro Funding round collections",
kind FULL
);

@DEF(collection_source, 'OP_ATLAS');
@DEF(collection_namespace, 'retro-funding');

WITH app AS (
SELECT DISTINCT
project_id,
project_name,
round_id
FROM oso.stg_op_atlas_application
WHERE
round_id IN ('7', '8')
AND status = 'submitted'
AND created_at BETWEEN '2025-02-01' AND '2025-03-08'
),

projects_by_collection AS (
SELECT DISTINCT
@collection_source AS collection_source,
@collection_namespace AS collection_namespace,
CONCAT(app.round_id, '-', '1') AS collection_name,
CASE
WHEN app.round_id = '7'
THEN 'Retro Funding S7: Developer Tooling'
WHEN app.round_id = '8'
THEN 'Retro Funding S7: Onchain Builders'
ELSE NULL
END AS collection_display_name,
projects.project_source,
projects.project_namespace,
projects.project_name,
app.project_id
FROM app
JOIN oso.stg_op_atlas_project AS projects
ON app.project_id = projects.project_id
)
SELECT
@oso_id(collection_source, collection_namespace, collection_name)
AS collection_id,
collection_source,
collection_namespace,
collection_name,
collection_display_name,
project_id,
project_source,
project_namespace,
project_name
FROM projects_by_collection
Original file line number Diff line number Diff line change
@@ -0,0 +1,19 @@
MODEL (
name oso.int_projects_by_collection_in_ossd,
description "Many-to-many mapping of projects to OSSD collections",
kind FULL
);

SELECT
stg_ossd__current_collections.collection_id,
stg_ossd__current_collections.collection_source,
stg_ossd__current_collections.collection_namespace,
stg_ossd__current_collections.collection_name,
stg_ossd__current_projects.project_id,
stg_ossd__current_projects.project_source,
stg_ossd__current_projects.project_namespace,
stg_ossd__current_projects.project_name
FROM oso.stg_ossd__current_collections AS stg_ossd__current_collections
CROSS JOIN UNNEST(stg_ossd__current_collections.projects) AS cc(project_name)
INNER JOIN oso.stg_ossd__current_projects AS stg_ossd__current_projects
ON stg_ossd__current_projects.project_name = cc.project_name
Original file line number Diff line number Diff line change
@@ -0,0 +1,45 @@
MODEL (
name oso.int_projects_to_projects,
description 'Many to many mapping of OSSD defined projects to externally defined projects',
dialect trino,
kind FULL
);

WITH artifacts_by_project_source AS (
SELECT
directory.project_id AS ossd_project_id,
directory.project_source AS ossd_project_source,
directory.project_namespace AS ossd_project_namespace,
directory.project_name AS ossd_project_name,
ossd_projects.display_name AS ossd_display_name,
external.project_id AS external_project_id,
external.project_source AS external_project_source,
external.project_namespace AS external_project_namespace,
external.project_name AS external_project_name,
external_projects.display_name AS external_display_name,
directory.artifact_id
FROM oso.int_artifacts_by_project AS directory
JOIN oso.int_artifacts_by_project AS external
ON directory.artifact_id = external.artifact_id
AND directory.project_source = 'OSS_DIRECTORY'
AND external.project_source != 'OSS_DIRECTORY'
AND directory.project_id != external.project_id
JOIN oso.int_projects AS ossd_projects
ON directory.project_id = ossd_projects.project_id
JOIN oso.int_projects AS external_projects
ON external.project_id = external_projects.project_id
)

SELECT DISTINCT
ossd_project_id,
ossd_project_source,
ossd_project_namespace,
ossd_project_name,
ossd_display_name,
external_project_id,
external_project_source,
external_project_namespace,
external_project_name,
external_display_name,
artifact_id
FROM artifacts_by_project_source
Original file line number Diff line number Diff line change
@@ -0,0 +1,16 @@
MODEL (
name oso.stg_op_atlas_application,
description 'Staging model for OP Atlas project applications',
dialect trino,
kind FULL
);

SELECT
@oso_id('OP_ATLAS', project_id) AS project_id, /* Translating op-atlas project_id to OSO project_id */
project_id::VARCHAR AS project_name,
attestation_id::VARCHAR AS attestation_id,
created_at::TIMESTAMP AS created_at,
updated_at::TIMESTAMP AS updated_at,
round_id::VARCHAR AS round_id,
status::VARCHAR AS status
FROM @oso_source('bigquery.op_atlas.application')
Original file line number Diff line number Diff line change
Expand Up @@ -17,7 +17,7 @@ SELECT
banner_url::VARCHAR,
twitter::VARCHAR,
mirror::VARCHAR,
open_source_observer_slug::VARCHAR,
TRIM(LOWER(open_source_observer_slug))::VARCHAR AS open_source_observer_slug,
created_at::TIMESTAMP,
updated_at::TIMESTAMP,
deleted_at::TIMESTAMP
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -16,8 +16,8 @@ SELECT
@oso_id('OP_ATLAS', repos.project_id) AS project_id, /* Translating op-atlas project_id to OSO project_id */
repos.id AS artifact_source_id,
'GITHUB' AS artifact_source,
@url_parts(repos.url, 2) AS artifact_namespace,
@url_parts(repos.url, 3) AS artifact_name,
LOWER(@url_parts(repos.url, 2)) AS artifact_namespace,
LOWER(@url_parts(repos.url, 3)) AS artifact_name,
repos.url AS artifact_url,
'REPOSITORY' AS artifact_type
/* repos.created_at, */ /* repos.updated_at, */ /* repos.verified as is_verified, */ /* repos.open_source as is_open_source, */ /* repos.contains_contracts, */ /* repos.crate as contains_crates, */ /* repos.npm_package as contains_npm */
Expand Down
Loading