|
| 1 | +create or replace function get_analysis(studyId character varying, analysisState analysis_state[], pageLimit integer, pageOffset integer) |
| 2 | +returns table ( |
| 3 | + -- Analysis table |
| 4 | + id character varying, study_id character varying, type analysis_type, state analysis_state, |
| 5 | + analysis_schema_id integer, analysis_data_id integer, created_at timestamp,updated_at timestamp, |
| 6 | + -- File table |
| 7 | + file_id character varying, file_analysis_id character varying, file_study_id character varying, name text, |
| 8 | + size bigint, md5 character, access access_type, file_type file_type, |
| 9 | + data_type character varying, info json, |
| 10 | + -- Sampleset table |
| 11 | + analysis_id character varying, sampleset_sample_id character varying, |
| 12 | + -- Sample table |
| 13 | + sample_id character varying, |
| 14 | + sample_specimen_id character varying, sample_submitter_id text, legacy_sample_type legacy_sample_type, |
| 15 | + sample_type sample_type, matched_normal_submitter_sample_id character varying, |
| 16 | + -- Specimen table |
| 17 | + specimen_id character varying, specimen_donor_id character varying, submitter_specimen_id text, specimen_class specimen_class, |
| 18 | + legacy_specimen_type legacy_specimen_type, specimen_type specimen_type, tissue_source tissue_source_type, tumour_normal_designation tumour_normal_designation_type, |
| 19 | + -- Donor table |
| 20 | + donor_donor_id character varying, submitter_donor_id text, gender gender, |
| 21 | + donor_study_id character varying, |
| 22 | + -- info table |
| 23 | + donor_info json,sample_info json, specimen_info json |
| 24 | +) as |
| 25 | +$$ |
| 26 | + begin |
| 27 | + -- How this script works: analysis_file_join is the result of joining Analysis table with File table, and getting file info from Info table. |
| 28 | + -- take the result of analysis_file_join and join Sampleset, Sample, Specimen, and Donor table as well as the info columns. |
| 29 | + RETURN QUERY |
| 30 | + SELECT analysis_file_sampleset_join.*, |
| 31 | + sample.id AS sample_id, |
| 32 | + sample.specimen_id AS sample_specimen_id, |
| 33 | + sample.submitter_id AS sample_submitter_id, |
| 34 | + sample.legacy_type AS legacy_sample_type, |
| 35 | + sample.type AS sample_type, |
| 36 | + sample.matched_normal_submitter_sample_id, |
| 37 | + specimen.id AS specimen_id, |
| 38 | + specimen.donor_id AS specimen_donor_id, |
| 39 | + specimen.submitter_id AS submitter_specimen_id, |
| 40 | + specimen.class AS specimen_class, |
| 41 | + specimen.legacy_type AS legacy_specimen_type, |
| 42 | + specimen.type AS speciment_type, |
| 43 | + specimen.tissue_source, |
| 44 | + specimen.tumour_normal_designation, |
| 45 | + donor.id AS donor_donor_id, |
| 46 | + donor.submitter_id AS submitter_donor_id, |
| 47 | + donor.gender, |
| 48 | + donor.study_id AS donor_study_id, |
| 49 | + donor_info.info AS donor_info, |
| 50 | + sample_info.info AS sample_info, |
| 51 | + specimen_info.info AS specimen_info |
| 52 | + |
| 53 | + FROM SAMPLE |
| 54 | + INNER JOIN (SELECT analysis_file_join.*, |
| 55 | + sampleset.analysis_id, |
| 56 | + sampleset.sample_id AS sampleset_sample_id |
| 57 | + FROM sampleset |
| 58 | + INNER JOIN ( |
| 59 | + SELECT * FROM ( |
| 60 | + SELECT * FROM analysis WHERE analysis.study_id = studyId AND analysis.state = ANY(analysisState) |
| 61 | + ORDER BY analysis.id ASC |
| 62 | + LIMIT pageLimit |
| 63 | + OFFSET pageOffset |
| 64 | + ) AS filtered_analysis |
| 65 | + JOIN ( SELECT filtered_file.id AS file_id, |
| 66 | + filtered_file.analysis_id AS file_analysis_id, |
| 67 | + filtered_file.study_id AS file_study_id, |
| 68 | + filtered_file.name, |
| 69 | + filtered_file.size, |
| 70 | + filtered_file.md5, |
| 71 | + filtered_file.access, |
| 72 | + filtered_file.type AS file_type, |
| 73 | + filtered_file.data_type, |
| 74 | + info.info |
| 75 | + FROM (SELECT * FROM file WHERE file.study_id = studyId ) AS filtered_file |
| 76 | + JOIN info ON filtered_file.id = info.id AND info.id_type = 'File') |
| 77 | + AS file_info |
| 78 | + ON filtered_analysis.id = file_info.file_analysis_id |
| 79 | + ) AS analysis_file_join |
| 80 | + ON analysis_file_join.id = sampleset.analysis_id ) |
| 81 | + AS analysis_file_sampleset_join |
| 82 | + ON analysis_file_sampleset_join.sampleset_sample_id = sample.id |
| 83 | + LEFT JOIN info sample_info ON analysis_file_sampleset_join.sampleset_sample_id = sample_info.id AND sample_info.id_type = 'Sample' |
| 84 | + INNER JOIN specimen ON specimen.id = sample.specimen_id |
| 85 | + LEFT JOIN info AS specimen_info ON specimen_info.id = specimen.id AND specimen_info.id_type = 'Specimen' |
| 86 | + INNER JOIN donor ON donor.id = specimen.donor_id |
| 87 | + LEFT JOIN info AS donor_info ON donor_info.id = donor.id AND donor_info.id_type = 'Donor' |
| 88 | + ORDER BY analysis_file_sampleset_join.analysis_id ASC ; |
| 89 | + |
| 90 | +end; |
| 91 | +$$ |
| 92 | +language plpgsql; |
0 commit comments