Merge pull request #2986 from solgenomics/topic/file_upload
[sgn.git] / db / 00065 / RedefineStockViews.pm
blob57fef0c19ec7b833b8bdb6498c830a746f06f145
1 #!/usr/bin/env perl
4 =head1 NAME
6 RedefineStockViews.pm
8 =head1 SYNOPSIS
10 mx-run RedefineStockViews [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 views that store stocks (accessions, plots, plants) to exclude obsolete stocks
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 RedefineStockViews;
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.accessions;
56 CREATE MATERIALIZED VIEW public.accessions AS
57 SELECT stock.stock_id AS accession_id,
58 stock.uniquename AS accession_name
59 FROM stock
60 WHERE stock.type_id = (SELECT cvterm_id from cvterm where cvterm.name = 'accession') AND is_obsolete = 'f'
61 GROUP BY stock.stock_id, stock.uniquename
62 WITH DATA;
63 CREATE UNIQUE INDEX accessions_idx ON public.accessions(accession_id) WITH (fillfactor=100);
64 ALTER MATERIALIZED VIEW accessions OWNER TO web_usr;
66 DROP MATERIALIZED VIEW public.plots;
68 CREATE MATERIALIZED VIEW public.plots AS
69 SELECT stock.stock_id AS plot_id,
70 stock.uniquename AS plot_name
71 FROM stock
72 WHERE stock.type_id = (SELECT cvterm_id from cvterm where cvterm.name = 'plot') AND is_obsolete = 'f'
73 GROUP BY public.stock.stock_id, public.stock.uniquename
74 WITH DATA;
75 CREATE UNIQUE INDEX plots_idx ON public.plots(plot_id) WITH (fillfactor=100);
76 ALTER MATERIALIZED VIEW plots OWNER TO web_usr;
78 DROP MATERIALIZED VIEW public.plants;
80 CREATE MATERIALIZED VIEW public.plants AS
81 SELECT stock.stock_id AS plant_id,
82 stock.uniquename AS plant_name
83 FROM stock
84 WHERE stock.type_id = (SELECT cvterm_id from cvterm where cvterm.name = 'plant') AND is_obsolete = 'f'
85 GROUP BY public.stock.stock_id, public.stock.uniquename
86 WITH DATA;
87 CREATE UNIQUE INDEX plants_idx ON public.plants(plant_id) WITH (fillfactor=100);
88 ALTER MATERIALIZED VIEW plants OWNER TO web_usr;
92 EOSQL
94 print "You're done!\n";
98 ####
99 1; #
100 ####