|
| 1 | + |
| 2 | +package SGN::Controller::AJAX::ValidatedTrials; |
| 3 | + |
| 4 | +use Moose; |
| 5 | + |
| 6 | +use Data::Dumper; |
| 7 | +use File::Slurp; |
| 8 | +use File::Spec qw | catfile |; |
| 9 | +use File::Path qw(rmtree); |
| 10 | +use JSON::Any; |
| 11 | +use File::Basename qw | basename |; |
| 12 | +use DateTime; |
| 13 | +use Bio::Chado::Schema; |
| 14 | +use CXGN::Dataset::File; |
| 15 | +use CXGN::Phenotypes::File; |
| 16 | +use CXGN::Phenotypes::PhenotypeMatrix; |
| 17 | +use SGN::Controller::AJAX::Dataset; |
| 18 | +use CXGN::BreedersToolbox::Projects; |
| 19 | +use JSON; |
| 20 | + |
| 21 | + |
| 22 | +BEGIN { extends 'Catalyst::Controller::REST' }; |
| 23 | + |
| 24 | +__PACKAGE__->config( |
| 25 | + default => 'application/json', |
| 26 | + stash_key => 'rest', |
| 27 | + map => { 'application/json' => 'JSON' }, |
| 28 | + ); |
| 29 | + |
| 30 | + |
| 31 | + |
| 32 | +sub grab_data :Path('/ajax/validatedtrials/grabdata') Args(0) { |
| 33 | + my $self = shift; |
| 34 | + my $c = shift; |
| 35 | + my $dbh = $c->dbc->dbh(); |
| 36 | + my $schema = $c->dbic_schema("Bio::Chado::Schema"); |
| 37 | + |
| 38 | + |
| 39 | + |
| 40 | + my $trials_sql = qq{ |
| 41 | + SELECT project."name", |
| 42 | + nd_geolocation.description as location, |
| 43 | + validated_prop.value AS trait_name |
| 44 | + FROM project |
| 45 | + JOIN projectprop AS validated_prop ON validated_prop.project_id = project.project_id |
| 46 | + JOIN projectprop AS location_prop ON location_prop.project_id = project.project_id |
| 47 | + JOIN nd_geolocation ON nd_geolocation.nd_geolocation_id = location_prop.value::integer |
| 48 | + WHERE validated_prop.type_id = (SELECT cvterm_id FROM cvterm WHERE name = 'validated_phenotype') |
| 49 | + AND location_prop.type_id = (SELECT cvterm_id FROM cvterm WHERE name = 'project location') |
| 50 | + GROUP BY project."name",location, trait_name; |
| 51 | + }; |
| 52 | + |
| 53 | + my @validated_projects; |
| 54 | + eval { |
| 55 | + # Prepare and execute the query |
| 56 | + my $sth_trial = $dbh->prepare($trials_sql); |
| 57 | + $sth_trial->execute(); |
| 58 | + |
| 59 | + # Collect project names from the query result |
| 60 | + while (my ($project_name, $project_location, $validated_trait) = $sth_trial->fetchrow_array) { |
| 61 | + # Split the validated_trait into two parts using '|' as the separator |
| 62 | + my ($trait, $username) = split(/\|/, $validated_trait, 2); |
| 63 | + |
| 64 | + # Store each row's data in a hash reference |
| 65 | + my $project_data = { |
| 66 | + name => $project_name, |
| 67 | + project_location => $project_location, |
| 68 | + validated_trait => $trait, # First part |
| 69 | + username => $username, # Second part |
| 70 | + }; |
| 71 | + |
| 72 | + # Push the hash reference into the array |
| 73 | + push @validated_projects, $project_data; |
| 74 | + } |
| 75 | + |
| 76 | + # print STDERR Dumper \@validated_projects; |
| 77 | + |
| 78 | + }; |
| 79 | + |
| 80 | + my $json = JSON->new; |
| 81 | + $c->stash->{rest} = { data => \@validated_projects }; |
| 82 | + |
| 83 | + # Explicitly encode the response as JSON |
| 84 | + my $encoded_response = $json->encode({ data => \@validated_projects }); |
| 85 | + $c->response->body($encoded_response); |
| 86 | + |
| 87 | + if ($@) { |
| 88 | + $c->response->body("Failed to search data: $@"); |
| 89 | + return; |
| 90 | + } |
| 91 | +} |
| 92 | + |
| 93 | +sub get_coordinate :Path('/ajax/validatedtrials/getcoordinates') Args(0) { |
| 94 | + |
| 95 | + my ($self, $c) = @_; |
| 96 | + |
| 97 | + my $sp_person_id = $c->user() ? $c->user->get_object()->get_sp_person_id() : undef; |
| 98 | + my $schema = $c->dbic_schema("Bio::Chado::Schema", undef, $sp_person_id); |
| 99 | + my $dbh = $c->dbc->dbh(); |
| 100 | + |
| 101 | + |
| 102 | + # Parse the input JSON to get the list of location names |
| 103 | + my $locations_json = $c->req->param('locNames'); |
| 104 | + my $location_names = decode_json($locations_json); |
| 105 | + |
| 106 | + # Escape the location names for SQL query |
| 107 | + my $placeholders = join(", ", ("?") x @$location_names); |
| 108 | + |
| 109 | + # Prepare and execute the SQL query |
| 110 | + my $sql = " |
| 111 | + SELECT DISTINCT p.name, p.project_id, ng.latitude, ng.longitude |
| 112 | + FROM project p |
| 113 | + JOIN nd_experiment_project nep ON nep.project_id = p.project_id |
| 114 | + JOIN nd_experiment ne ON ne.nd_experiment_id = nep.nd_experiment_id |
| 115 | + JOIN nd_geolocation ng ON ng.nd_geolocation_id = ne.nd_geolocation_id |
| 116 | + WHERE p.name IN ($placeholders) |
| 117 | + "; |
| 118 | + |
| 119 | + |
| 120 | + eval{ |
| 121 | + my $sth = $dbh->prepare($sql); |
| 122 | + $sth->execute(@{$location_names}); |
| 123 | + |
| 124 | + my @locations_with_coordinates; |
| 125 | + while (my ($name, $project_id, $latitude, $longitude) = $sth->fetchrow_array) { |
| 126 | + push @locations_with_coordinates, { name => $name, trial_id => $project_id, latitude => $latitude, longitude => $longitude }; |
| 127 | + } |
| 128 | + # Return the results as JSON |
| 129 | + $c->res->content_type('application/json'); |
| 130 | + $c->res->body(encode_json(\@locations_with_coordinates)); |
| 131 | + }; |
| 132 | + |
| 133 | + if ($@) { |
| 134 | + $c->res->status(500); |
| 135 | + $c->res->body(encode_json({ error => "Database error: $_" })); |
| 136 | + }; |
| 137 | + |
| 138 | +} |
| 139 | + |
| 140 | +sub get_phenotype :Path('/ajax/validatedtrials/getphenotype') Args(0){ |
| 141 | + |
| 142 | + my ($self, $c) = @_; |
| 143 | + |
| 144 | + my $sp_person_id = $c->user() ? $c->user->get_object()->get_sp_person_id() : undef; |
| 145 | + my $schema = $c->dbic_schema("Bio::Chado::Schema", undef, $sp_person_id); |
| 146 | + my $dbh = $c->dbc->dbh(); |
| 147 | + |
| 148 | + # Parse the input JSON to get the list of trial and trait pairs |
| 149 | + my $projects_json = $c->req->param('projectTrait'); |
| 150 | + my $projects_names = decode_json($projects_json); |
| 151 | + |
| 152 | + # Array to hold final results |
| 153 | + my @data; |
| 154 | + |
| 155 | + foreach my $project (@$projects_names) { |
| 156 | + my $trial_name = $project->{name}; |
| 157 | + my $trait_name = $project->{validated_trait}; |
| 158 | + |
| 159 | + # Skip if either trial or trait is missing |
| 160 | + next unless $trial_name && $trait_name; |
| 161 | + |
| 162 | + # Fetch phenotype data for this trial–trait pair, excluding outliers |
| 163 | + my $sql_phenotypes = " |
| 164 | + select p.name as location_name, s.uniquename as plot_name, s2.uniquename as accession, cvterm.name as trait, phenotype.value |
| 165 | + from phenotype |
| 166 | + join nd_experiment_phenotype nep ON nep.phenotype_id = phenotype.phenotype_id |
| 167 | + join nd_experiment_project nep2 on nep2.nd_experiment_id = nep.nd_experiment_id |
| 168 | + join nd_experiment_stock nes on nes.nd_experiment_id = nep.nd_experiment_id |
| 169 | + join phenotype p2 ON p2.phenotype_id = nep.phenotype_id |
| 170 | + join project p on p.project_id = nep2.project_id |
| 171 | + join cvterm on p2.cvalue_id = cvterm.cvterm_id |
| 172 | + join stock s on s.stock_id = nes.stock_id |
| 173 | + join stock_relationship sr on sr.subject_id = nes.stock_id |
| 174 | + join stock s2 on s2.stock_id = sr.object_id |
| 175 | + where p.name = ? |
| 176 | + and cvterm.name = ? |
| 177 | + and phenotype.phenotype_id not in ( select phenotype_id from phenotypeprop p3 WHERE p3.type_id = ( select cvterm_id from cvterm where name = 'phenotype_outlier')); |
| 178 | + "; |
| 179 | + |
| 180 | + eval { |
| 181 | + my $sth = $dbh->prepare($sql_phenotypes); |
| 182 | + $sth->execute($trial_name, $trait_name); |
| 183 | + |
| 184 | + while (my ($location, $plot, $accession, $trait, $value) = $sth->fetchrow_array) { |
| 185 | + push @data, { |
| 186 | + trial => $location, |
| 187 | + plot => $plot, |
| 188 | + accession => $accession, |
| 189 | + trait => $trait, |
| 190 | + value => $value, |
| 191 | + }; |
| 192 | + } |
| 193 | + }; |
| 194 | + |
| 195 | + # Handle errors |
| 196 | + if ($@) { |
| 197 | + warn "Error fetching phenotype data for trial '$trial_name' and trait '$trait_name': $@"; |
| 198 | + } |
| 199 | + } |
| 200 | + |
| 201 | + # Return the combined results as JSON |
| 202 | + $c->res->content_type('application/json'); |
| 203 | + $c->res->body(encode_json(\@data)); |
| 204 | + |
| 205 | + # Debugging: Print results |
| 206 | + # print Dumper \@data; |
| 207 | +} |
| 208 | + |
| 209 | + |
| 210 | +1; |
0 commit comments