Merge pull request #5205 from solgenomics/topic/generic_trial_upload
[sgn.git] / db / 00061 / RedefineTraitsView.pm
blob0d73375090c3d7592b9a34dcc674b1381a670f6f
1 #!/usr/bin/env perl
4 =head1 NAME
6 RedefineTraitsView.pm
8 =head1 SYNOPSIS
10 mx-run RedefineTraitsView [options] -H hostname -D dbname -u username [-F]
12 this is a subclass of L<CXGN::Metadata::Dbpatch>
13 see the perldoc of parent class for more details.
15 =head1 DESCRIPTION
17 This patch updates the materialized view that stores traits
19 =head1 AUTHOR
21 Bryan Ellerbrock<bje24@cornell.edu>
23 =head1 COPYRIGHT & LICENSE
25 Copyright 2010 Boyce Thompson Institute for Plant Research
27 This program is free software; you can redistribute it and/or modify
28 it under the same terms as Perl itself.
30 =cut
33 package RedefineTraitsView;
35 use Moose;
36 extends 'CXGN::Metadata::Dbpatch';
39 has '+description' => ( default => <<'' );
40 This patch updates the materialized view that stores traits
42 sub patch {
43 my $self=shift;
45 print STDOUT "Executing the patch:\n " . $self->name . ".\n\nDescription:\n ". $self->description . ".\n\nExecuted by:\n " . $self->username . " .";
47 print STDOUT "\nChecking if this db_patch was executed before or if previous db_patches have been executed.\n";
49 print STDOUT "\nExecuting the SQL commands.\n";
51 $self->dbh->do(<<EOSQL);
52 --do your SQL here
54 DROP MATERIALIZED VIEW public.traits;
56 CREATE MATERIALIZED VIEW public.traits AS
57 SELECT cvterm.cvterm_id AS trait_id,
58 (((cvterm.name::text || '|'::text) || db.name::text) || ':'::text) || dbxref.accession::text AS trait_name
59 FROM cvterm
60 JOIN dbxref ON cvterm.dbxref_id = dbxref.dbxref_id
61 JOIN db ON dbxref.db_id = db.db_id
62 WHERE cvterm.cvterm_id IN (SELECT cvterm_relationship.subject_id FROM cvterm_relationship JOIN cvterm on (cvterm_relationship.subject_id = cvterm.cvterm_id) where cvterm_relationship.type_id = (SELECT cvterm_id from cvterm where name = 'VARIABLE_OF') GROUP BY 1)
63 AND db.db_id =
64 (SELECT dbxref.db_id
65 FROM stock
66 JOIN nd_experiment_stock USING(stock_id)
67 JOIN nd_experiment_phenotype USING(nd_experiment_id)
68 JOIN phenotype USING(phenotype_id)
69 JOIN cvterm ON phenotype.cvalue_id = cvterm.cvterm_id
70 JOIN dbxref ON cvterm.dbxref_id = dbxref.dbxref_id LIMIT 1)
71 GROUP BY public.cvterm.cvterm_id, trait_name
72 WITH DATA;
73 CREATE UNIQUE INDEX traits_idx ON public.traits(trait_id) WITH (fillfactor=100);
74 ALTER MATERIALIZED VIEW traits OWNER TO web_usr;
78 EOSQL
80 print "You're done!\n";
84 ####
85 1; #
86 ####