Skip to content

Commit

Permalink
Merge pull request #60 from subugoe/sep_23
Browse files Browse the repository at this point in the history
Fix counting openalex pubs with different oa status, eg "10.1088/1742…
  • Loading branch information
njahn82 committed Oct 5, 2023
2 parents ac1deeb + c9eb6df commit 99bcb4d
Show file tree
Hide file tree
Showing 2 changed files with 74 additions and 50 deletions.
Binary file modified data/cr_upw.rda
Binary file not shown.
124 changes: 74 additions & 50 deletions inst/sql/cc_upw_cr.sql
Original file line number Diff line number Diff line change
@@ -1,68 +1,92 @@
# License Metadata Gaps
# Comparision of license metadata in Crossref with Unpaywall via OpenALEX per
# journal, year and country affiliation (Germany).
WITH oalex_cc_de AS (
SELECT DISTINCT cc_cr.doi,
# License Metadata Gaps
# Comparision of license metadata in Crossref with Unpaywall via OpenALEX per
# journal, year and country affiliation (Germany).
#
# 1. Get hybrid oa articles
WITH
hybrid_oa_upw AS (
SELECT
DISTINCT oalex.doi
FROM
`subugoe-collaborative.openalex.works` AS oalex
WHERE
open_access.oa_status = "hybrid" ),
# 2. Germany OA evidence per source
oalex_cc_de AS (
SELECT
DISTINCT cc_cr.doi,
cc_cr.issn_l,
cc_cr.cr_year,
CASE
WHEN open_access.oa_status = "hybrid" THEN 1
ELSE 0
END AS upw_hybrid,
WHEN EXISTS ( SELECT doi FROM hybrid_oa_upw WHERE doi = cc_cr.doi) THEN 1
ELSE
0
END
AS upw_hybrid,
CASE
WHEN (
cc IS NOT NULL
AND vor = 1
) THEN 1
ELSE 0
END AS cr_hybrid,
WHEN ( cc IS NOT NULL AND vor = 1 ) THEN 1
ELSE
0
END
AS cr_hybrid,
CASE
WHEN country_code = "DE" THEN 1
ELSE 0
END AS germany
FROM `subugoe-collaborative.hoaddata.cc_md` AS cc_cr
LEFT JOIN `subugoe-collaborative.openalex.works` AS oalex ON LOWER(cc_cr.doi) = LOWER(oalex.doi)
LEFT OUTER JOIN `subugoe-collaborative.hoaddata.cr_openalex_inst_full` AS oalex_inst ON LOWER(cc_cr.doi) = LOWER(oalex_inst.doi)
),
u AS (
SELECT DISTINCT issn_l,
ELSE
0
END
AS germany
FROM
`subugoe-collaborative.hoaddata.cc_md` AS cc_cr
LEFT OUTER JOIN
`subugoe-collaborative.hoaddata.cr_openalex_inst_full` AS oalex_inst
ON
LOWER(cc_cr.doi) = LOWER(oalex_inst.doi) ),
# 3. Global stats
u AS (
SELECT
DISTINCT issn_l,
cr_year,
COUNT(DISTINCT doi) OVER (PARTITION BY issn_l, cr_year) AS article_total,
SUM(upw_hybrid) OVER (PARTITION BY issn_l, cr_year) AS upw_hybrid_total,
SUM(cr_hybrid) OVER (PARTITION BY issn_l, cr_year) AS cr_hybrid_total,
CAST("Global" AS STRING) AS cat
FROM (
SELECT DISTINCT cc_cr.doi,
cc_cr.issn_l,
cc_cr.cr_year,
CASE
WHEN open_access.oa_status = "hybrid" THEN 1
ELSE 0
END AS upw_hybrid,
CASE
WHEN (
cc IS NOT NULL
AND vor = 1
) THEN 1
ELSE 0
END AS cr_hybrid
FROM `subugoe-collaborative.hoaddata.cc_md` AS cc_cr
LEFT JOIN `subugoe-collaborative.openalex.works` AS oalex ON LOWER(cc_cr.doi) = LOWER(oalex.doi)
)
UNION ALL
(
SELECT DISTINCT issn_l,
SELECT
DISTINCT cc_cr.doi,
cc_cr.issn_l,
cc_cr.cr_year,
CASE
WHEN EXISTS ( SELECT doi FROM hybrid_oa_upw WHERE doi = cc_cr.doi) THEN 1
ELSE
0
END
AS upw_hybrid,
CASE
WHEN ( cc IS NOT NULL AND vor = 1 ) THEN 1
ELSE
0
END
AS cr_hybrid
FROM
`subugoe-collaborative.hoaddata.cc_md` AS cc_cr )
# Combine with Germany stats
UNION ALL (
SELECT
DISTINCT issn_l,
cr_year,
COUNT(DISTINCT doi) OVER (PARTITION BY issn_l, cr_year) AS article_total,
SUM(upw_hybrid) OVER (PARTITION BY issn_l, cr_year) AS upw_hybrid_total,
SUM(cr_hybrid) OVER (PARTITION BY issn_l, cr_year) AS cr_hybrid_total,
CAST("Germany" AS STRING) AS cat
FROM oalex_cc_de
WHERE germany = 1
)
ORDER BY issn_l,
FROM
oalex_cc_de
WHERE
germany = 1 )
ORDER BY
issn_l,
cr_year,
cat
)
SELECT *
FROM u
cat )
SELECT
*
FROM
u

0 comments on commit 99bcb4d

Please sign in to comment.