Skip to content

Commit

Permalink
use regular views instead of materialized views (#10793)
Browse files Browse the repository at this point in the history
  • Loading branch information
onursumer committed May 14, 2024
1 parent e073a31 commit 77d07e0
Show file tree
Hide file tree
Showing 4 changed files with 159 additions and 15 deletions.
Original file line number Diff line number Diff line change
Expand Up @@ -55,7 +55,7 @@ public List<ClinicalDataCount> getPatientClinicalDataCounts(StudyViewFilter stud

@Override
public List<String> getClinicalDataAttributeNames(ClinicalAttributeDataSource clinicalAttributeDataSource, ClinicalAttributeDataType dataType) {
String tableName = clinicalAttributeDataSource.getValue().toLowerCase() + "_clinical_attribute_" + dataType.getValue().toLowerCase();
String tableName = clinicalAttributeDataSource.getValue().toLowerCase() + "_clinical_attribute_" + dataType.getValue().toLowerCase() + "_view";
return mapper.getClinicalAttributeNames(tableName);
}

Expand Down
144 changes: 144 additions & 0 deletions src/main/resources/db-scripts/columnar/views.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,144 @@
DROP VIEW IF EXISTS sample_clinical_attribute_numeric_view;
DROP VIEW IF EXISTS sample_clinical_attribute_categorical_view;
DROP VIEW IF EXISTS patient_clinical_attribute_numeric_view;
DROP VIEW IF EXISTS patient_clinical_attribute_categorical_view;
DROP VIEW IF EXISTS sample_view;
DROP VIEW IF EXISTS sample_list_view;
DROP VIEW IF EXISTS genomic_event_view;

CREATE VIEW sample_clinical_attribute_numeric_view
AS
SELECT concat(cs.cancer_study_identifier, '_', s.stable_id) as sample_unique_id,
concat(cs.cancer_study_identifier, '_', p.stable_id) as patient_unique_id,
clinical_sample.attr_id as attribute_name,
cast(clinical_sample.attr_value as float) as attribute_value,
cs.cancer_study_identifier as cancer_study_identifier
FROM cancer_study cs
INNER JOIN patient p on cs.cancer_study_id = p.cancer_study_id
INNER JOIN sample s on p.internal_id = s.patient_id
INNER JOIN clinical_sample ON s.internal_id = clinical_sample.internal_id
WHERE match(clinical_sample.attr_value, '^[\d\.]+$');

CREATE VIEW sample_clinical_attribute_categorical_view
AS
SELECT concat(cs.cancer_study_identifier, '_', s.stable_id) as sample_unique_id,
concat(cs.cancer_study_identifier, '_', p.stable_id) as patient_unique_id,
cl.attr_id as attribute_name,
cl.attr_value as attribute_value,
cs.cancer_study_identifier as cancer_study_identifier
FROM cancer_study cs
INNER JOIN patient p on cs.cancer_study_id = p.cancer_study_id
INNER JOIN sample s on p.internal_id = s.patient_id
INNER JOIN clinical_sample cl on s.internal_id = cl.internal_id
WHERE NOT match(cl.attr_value, '^[\d\.]+$');

CREATE VIEW patient_clinical_attribute_numeric_view
AS
SELECT concat(cs.cancer_study_identifier, '_', p.stable_id) as patient_unique_id,
cp.attr_id as attribute_name,
cast(cp.attr_value as float) as attribute_value,
cs.cancer_study_identifier as cancer_study_identifier
FROM cancer_study cs
INNER JOIN patient p on cs.cancer_study_id = p.cancer_study_id
INNER JOIN clinical_patient cp on p.internal_id = cp.internal_id
WHERE match(cp.attr_value, '^[\d\.]+$');

CREATE VIEW patient_clinical_attribute_categorical_view
AS
SELECT concat(cs.cancer_study_identifier, '_', p.stable_id) as patient_unique_id,
cp.attr_id as attribute_name,
cp.attr_value as attribute_value,
cs.cancer_study_identifier as cancer_study_identifier
FROM cancer_study cs
INNER JOIN patient p on cs.cancer_study_id = p.cancer_study_id
INNER JOIN clinical_patient cp on p.internal_id = cp.internal_id
WHERE NOT match(cp.attr_value, '^[\d\.]+$');

CREATE VIEW sample_view
AS
SELECT concat(cs.cancer_study_identifier, '_', sample.stable_id) as sample_unique_id,
base64Encode(sample.stable_id) as sample_unique_id_base64,
sample.stable_id as sample_stable_id,
concat(cs.cancer_study_identifier, '_', p.stable_id) as patient_unique_id,
p.stable_id as patient_stable_id,
base64Encode(p.stable_id) as patient_unique_id_base64,
cs.cancer_study_identifier as cancer_study_identifier
FROM sample
INNER JOIN patient p on sample.patient_id = p.internal_id
INNER JOIN cancer_study cs on p.cancer_study_id = cs.cancer_study_id;

CREATE VIEW sample_list_view
AS
SELECT concat(cs.cancer_study_identifier, '_', s.stable_id) as sample_unique_id,
sl.stable_id as sample_list_stable_id,
sl.name as name,
cs.cancer_study_identifier as cancer_study_identifier
FROM sample_list as sl
INNER JOIN sample_list_list AS sll on sll.list_id = sl.list_id
INNER JOIN sample AS s on s.internal_id = sll.sample_id
INNER JOIN cancer_study cs on sl.cancer_study_id = cs.cancer_study_id;

CREATE VIEW genomic_event_view
AS
SELECT concat(cs.cancer_study_identifier, '_', sample.stable_id) as sample_unique_id,
me.protein_change as variant,
'mutation' as variant_type,
gene.hugo_gene_symbol as hugo_gene_symbol,
gp.stable_id as gene_panel_stable_id,
cs.cancer_study_identifier as cancer_study_identifier,
g.stable_id as genetic_profile_stable_id
FROM mutation
LEFT JOIN mutation_event as me on mutation.mutation_event_id = me.mutation_event_id
LEFT JOIN sample_profile sp
on mutation.sample_id = sp.sample_id and mutation.genetic_profile_id = sp.genetic_profile_id
LEFT JOIN gene_panel gp on sp.panel_id = gp.internal_id
LEFT JOIN genetic_profile g on sp.genetic_profile_id = g.genetic_profile_id
LEFT JOIN cancer_study cs on g.cancer_study_id = cs.cancer_study_id
LEFT JOIN sample on mutation.sample_id = sample.internal_id
LEFT JOIN gene on mutation.entrez_gene_id = gene.entrez_gene_id
UNION ALL
SELECT concat(cs.cancer_study_identifier, '_', sample.stable_id) as sample_unique_id,
toString(ce.alteration) as variant,
'cna' as variant_type,
gene.hugo_gene_symbol as hugo_gene_symbol,
gp.stable_id as gene_panel_stable_id,
cs.cancer_study_identifier as cancer_study_identifier,
gp.stable_id as genetic_profile_stable_id
FROM cna_event ce
INNER JOIN sample_cna_event sce ON ce.cna_event_id = sce.cna_event_id
INNER JOIN sample_profile sp ON sce.sample_id = sp.sample_id AND sce.genetic_profile_id = sp.genetic_profile_id
INNER JOIN gene_panel gp ON sp.panel_id = gp.internal_id
INNER JOIN genetic_profile g ON sp.genetic_profile_id = g.genetic_profile_id
INNER JOIN cancer_study cs ON g.cancer_study_id = cs.cancer_study_id
INNER JOIN sample ON sce.sample_id = sample.internal_id
INNER JOIN gene ON ce.entrez_gene_id = gene.entrez_gene_id
UNION ALL
SELECT concat(cs.cancer_study_identifier, '_', s.stable_id) as sample_unique_id,
event_info as variant,
'structural_variant' as variant_type,
gene1.hugo_gene_symbol as hugo_gene_symbol,
gene_panel.stable_id as gene_panel_stable_id,
cs.cancer_study_identifier as cancer_study_identifier,
gp.stable_id as genetic_profile_stable_id
FROM structural_variant sv
INNER JOIN genetic_profile gp ON sv.genetic_profile_id = gp.genetic_profile_id
INNER JOIN sample s ON sv.sample_id = s.internal_id
INNER JOIN cancer_study cs ON gp.cancer_study_id = cs.cancer_study_id
INNER JOIN gene gene1 ON sv.site1_entrez_gene_id = gene1.entrez_gene_id
INNER JOIN sample_profile on s.internal_id = sample_profile.sample_id
INNER JOIN gene_panel on sample_profile.panel_id = gene_panel.internal_id
UNION ALL
SELECT concat(cs.cancer_study_identifier, '_', s.stable_id) as sample_unique_id,
event_info as variant,
'structural_variant' as variant_type,
gene2.hugo_gene_symbol as hugo_gene_symbol,
gene_panel.stable_id as gene_panel_stable_id,
cs.cancer_study_identifier as cancer_study_identifier,
gp.stable_id as genetic_profile_stable_id
FROM structural_variant sv
INNER JOIN genetic_profile gp ON sv.genetic_profile_id = gp.genetic_profile_id
INNER JOIN sample s ON sv.sample_id = s.internal_id
INNER JOIN cancer_study cs ON gp.cancer_study_id = cs.cancer_study_id
INNER JOIN gene gene2 ON sv.site2_entrez_gene_id = gene2.entrez_gene_id
INNER JOIN sample_profile on s.internal_id = sample_profile.sample_id
INNER JOIN gene_panel on sample_profile.panel_id = gene_panel.internal_id;
Original file line number Diff line number Diff line change
Expand Up @@ -7,7 +7,7 @@
<if test="studyViewFilter.studyIds != null and !studyViewFilter.studyIds.isEmpty()">
INTERSECT
SELECT sample_unique_id
FROM sample_columnstore
FROM sample_view
WHERE cancer_study_identifier IN
<foreach item="studyId" collection="studyViewFilter.studyIds" open="(" separator="," close=")">
#{studyId}
Expand All @@ -16,7 +16,7 @@
<if test="studyViewFilter.sampleIdentifiers != null and !studyViewFilter.sampleIdentifiers.isEmpty()">
INTERSECT
SELECT sample_unique_id
FROM sample_columnstore
FROM sample_view
WHERE sample_unique_id IN
<foreach item="sampleIdentifier" collection="studyViewFilter.sampleIdentifiers" open="(" separator="," close=")">
'${sampleIdentifier.studyId}_${sampleIdentifier.sampleId}'
Expand All @@ -26,7 +26,7 @@
<foreach item="profileGroup" collection="studyViewFilter.geneFilters">
<foreach item="geneFilterQueryList" collection="profileGroup.getGeneQueries()" open="INTERSECT" separator="INTERSECT">
SELECT sample_unique_id
FROM genomic_event
FROM genomic_event_view
<where>
genetic_profile_stable_id IN
<foreach item="molecularProfileId" collection="profileGroup.getMolecularProfileIds()" open="(" separator="," close=")">
Expand All @@ -46,15 +46,15 @@
<foreach item="clinicalDataFilter" collection="categorizedClinicalDataCountFilter.getSampleNumericalClinicalDataFilters()" open="INTERSECT" separator="INTERSECT">
<include refid="numericalClinicalDataCountFilter">
<property name="unique_id" value="sample_unique_id"/>
<property name="table_name" value="sample_clinical_attribute_numeric"/>
<property name="table_name" value="sample_clinical_attribute_numeric_view"/>
</include>
</foreach>
</if>
<if test="categorizedClinicalDataCountFilter.getSampleCategoricalClinicalDataFilters() != null and !categorizedClinicalDataCountFilter.getSampleCategoricalClinicalDataFilters().isEmpty()">
<foreach item="clinicalDataFilter" collection="categorizedClinicalDataCountFilter.getSampleCategoricalClinicalDataFilters()" open="INTERSECT" separator="INTERSECT">
<include refid="categoricalClinicalDataCountFilter">
<property name="unique_id" value="sample_unique_id"/>
<property name="table_name" value="sample_clinical_attribute_categorical"/>
<property name="table_name" value="sample_clinical_attribute_categorical_view"/>
</include>
</foreach>
</if>
Expand All @@ -68,15 +68,15 @@
<foreach item="clinicalDataFilter" collection="categorizedClinicalDataCountFilter.getPatientNumericalClinicalDataFilters()" open="INTERSECT" separator="INTERSECT">
<include refid="numericalClinicalDataCountFilter">
<property name="unique_id" value="patient_unique_id"/>
<property name="table_name" value="patient_clinical_attribute_numeric"/>
<property name="table_name" value="patient_clinical_attribute_numeric_view"/>
</include>
</foreach>
</if>
<if test="categorizedClinicalDataCountFilter.getPatientCategoricalClinicalDataFilters() != null and !categorizedClinicalDataCountFilter.getPatientCategoricalClinicalDataFilters().isEmpty()">
<foreach item="clinicalDataFilter" collection="categorizedClinicalDataCountFilter.getPatientCategoricalClinicalDataFilters()" open="INTERSECT" separator="INTERSECT">
<include refid="categoricalClinicalDataCountFilter">
<property name="unique_id" value="patient_unique_id"/>
<property name="table_name" value="patient_clinical_attribute_categorical"/>
<property name="table_name" value="patient_clinical_attribute_categorical_view"/>
</include>
</foreach>
</if>
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -11,7 +11,7 @@
cancer_study_identifier as cancerStudyIdentifier,
sample_unique_id_base64 as uniqueSampleKey,
patient_unique_id_base64 as uniquePatientKey
FROM sample_columnstore
FROM sample_view
<where>
sample_unique_id IN ( <include refid="sampleUniqueIdsFromStudyViewFilter"/>)

Expand All @@ -31,7 +31,7 @@
COUNT(DISTINCT sample_unique_id) as numberOfProfiledCases,
COUNT(DISTINCT sample_unique_id) as numberOfAlteredCases,
COUNT(*) as totalCount
FROM genomic_event
FROM genomic_event_view
<where>
variant_type = 'mutation'
AND
Expand All @@ -53,7 +53,7 @@
attribute_name as attrId,
attribute_value as attrValue,
cancer_study_identifier as studyId
FROM sample_clinical_attribute_numeric
FROM sample_clinical_attribute_numeric_view
<where>
sample_unique_id IN (
<include refid="sampleUniqueIdsFromStudyViewFilter"/>
Expand All @@ -77,7 +77,7 @@
attribute_name as attrId,
attribute_value as attrValue,
cancer_study_identifier as studyId
FROM patient_clinical_attribute_numeric
FROM patient_clinical_attribute_numeric_view
<where>
patient_unique_id IN (
<include refid="getPatientIdsFromSampleIdFilters"/>
Expand Down Expand Up @@ -110,7 +110,7 @@
attribute_name as attributeId,
CASE WHEN attribute_value = 'NULL' THEN 'NA' ELSE attribute_value END AS value,
Count(*) as count
FROM ${table_name_prefix}_clinical_attribute_categorical
FROM ${table_name_prefix}_clinical_attribute_categorical_view
<where>
patient_unique_id IN ( <include refid="getPatientIdsFromSampleIdFilters"/>
<if test="applyPatientIdFilters == true">
Expand Down Expand Up @@ -144,15 +144,15 @@

<sql id="getSampleIdsFromPatientIds">
SELECT sample_unique_id
FROM sample_columnstore
FROM sample_view
<where>
patient_unique_id IN (<include refid="patientUniqueIdsFromStudyViewFilter"/>)
</where>
</sql>

<sql id="getPatientIdsFromSampleIdFilters">
SELECT patient_unique_id
FROM sample_columnstore
FROM sample_view
<where>
sample_unique_id IN (<include refid="sampleUniqueIdsFromStudyViewFilter"/>)
</where>
Expand Down

0 comments on commit 77d07e0

Please sign in to comment.