From: Chris Hilton Date: Mon, 19 Mar 2007 17:15:24 +0000 (+0000) Subject: Added cursory parsing of view, functions, and procedures (oh why!) X-Git-Tag: v0.11008~367 X-Git-Url: http://git.shadowcat.co.uk/gitweb/gitweb.cgi?a=commitdiff_plain;h=d31c185b86e092189dcec4d7afa9b98b4700fdc9;p=dbsrgits%2FSQL-Translator.git Added cursory parsing of view, functions, and procedures (oh why!) Added pre-processing for /*! comments from mysqldump Added mysql_parser_version parser arg for enabling parsing not-before-version comments from mysqldump --- diff --git a/lib/SQL/Translator/Parser/MySQL.pm b/lib/SQL/Translator/Parser/MySQL.pm index ffc178b..cd238dd 100644 --- a/lib/SQL/Translator/Parser/MySQL.pm +++ b/lib/SQL/Translator/Parser/MySQL.pm @@ -1,7 +1,7 @@ package SQL::Translator::Parser::MySQL; # ------------------------------------------------------------------- -# $Id: MySQL.pm,v 1.57 2007-02-19 23:35:27 duality72 Exp $ +# $Id: MySQL.pm,v 1.58 2007-03-19 17:15:24 duality72 Exp $ # ------------------------------------------------------------------- # Copyright (C) 2002-4 SQLFairy Authors # @@ -134,7 +134,7 @@ A subset of INSERT that we ignore: use strict; use vars qw[ $DEBUG $VERSION $GRAMMAR @EXPORT_OK ]; -$VERSION = sprintf "%d.%02d", q$Revision: 1.57 $ =~ /(\d+)\.(\d+)/; +$VERSION = sprintf "%d.%02d", q$Revision: 1.58 $ =~ /(\d+)\.(\d+)/; $DEBUG = 0 unless defined $DEBUG; use Data::Dumper; @@ -149,10 +149,12 @@ $::RD_ERRORS = 1; # Make sure the parser dies when it encounters an error $::RD_WARN = 1; # Enable warnings. This will warn on unused rules &c. $::RD_HINT = 1; # Give out hints to help fix problems. +use constant DEFAULT_PARSER_VERSION => 30000; + $GRAMMAR = << 'END_OF_GRAMMAR'; { - my ( $database_name, %tables, $table_order, @table_comments ); + my ( $database_name, %tables, $table_order, @table_comments, %views, $view_order, %procedures, $proc_order ); my $delimiter = ';'; } @@ -163,7 +165,7 @@ $GRAMMAR = << 'END_OF_GRAMMAR'; # failed. -ky # startrule : statement(s) eofile { - { tables => \%tables, database_name => $database_name } + { tables => \%tables, database_name => $database_name, views => \%views, procedures =>\%procedures } } eofile : /^\Z/ @@ -295,6 +297,48 @@ create : CREATE UNIQUE(?) /(index|key)/i index_name /on/i table_name '(' field_n ; } +create : CREATE /trigger/i NAME not_delimiter "$delimiter" + { + @table_comments = (); + } + +create : CREATE PROCEDURE NAME not_delimiter "$delimiter" + { + @table_comments = (); + my $func_name = $item[3]; + my $owner = ''; + my $sql = "$item[1] $item[2] $item[3] $item[4]"; + + $procedures{ $func_name }{'order'} = ++$proc_order; + $procedures{ $func_name }{'name'} = $func_name; + $procedures{ $func_name }{'owner'} = $owner; + $procedures{ $func_name }{'sql'} = $sql; + } + +PROCEDURE : /procedure/i + | /function/i + +create : CREATE algorithm /view/i NAME not_delimiter "$delimiter" + { + @table_comments = (); + my $view_name = $item[4]; + my $sql = "$item[1] $item[2] $item[3] $item[4] $item[5]"; + + # Hack to strip database from function calls in SQL + $sql =~ s#`\w+`\.(`\w+`\()##g; + + $views{ $view_name }{'order'} = ++$view_order; + $views{ $view_name }{'name'} = $view_name; + $views{ $view_name }{'sql'} = $sql; + } + +algorithm : /algorithm/i /=/ WORD + { + $return = "$item[1]=$item[3]"; + } + +not_delimiter : /.*?(?=$delimiter)/is + create_definition : constraint | index | field @@ -726,6 +770,10 @@ sub parse { return $translator->error("Error instantiating Parse::RecDescent ". "instance: Bad grammer"); } + + # Preprocess for MySQL-specific and not-before-version comments from mysqldump + my $parser_version = $translator->parser_args->{mysql_parser_version} || DEFAULT_PARSER_VERSION; + while ( $data =~ s#/\*!(\d{5})?(.*?)\*/#($1 && $1 > $parser_version ? '' : $2)#es ) {} my $result = $parser->startrule($data); return $translator->error( "Parse failed." ) unless defined $result; @@ -833,6 +881,27 @@ sub parse { ) or die $table->error; } } + + my @procedures = sort { + $result->{procedures}->{ $a }->{'order'} <=> $result->{procedures}->{ $b }->{'order'} + } keys %{ $result->{procedures} }; + foreach my $proc_name (@procedures) { + $schema->add_procedure( + name => $proc_name, + owner => $result->{procedures}->{$proc_name}->{owner}, + sql => $result->{procedures}->{$proc_name}->{sql}, + ); + } + + my @views = sort { + $result->{views}->{ $a }->{'order'} <=> $result->{views}->{ $b }->{'order'} + } keys %{ $result->{views} }; + foreach my $view_name (keys %{ $result->{views} }) { + $schema->add_view( + name => $view_name, + sql => $result->{views}->{$view_name}->{sql}, + ); + } return 1; } diff --git a/t/02mysql-parser.t b/t/02mysql-parser.t index ea3a7e1..c60cef7 100644 --- a/t/02mysql-parser.t +++ b/t/02mysql-parser.t @@ -10,7 +10,7 @@ use SQL::Translator::Schema::Constants; use Test::SQL::Translator qw(maybe_plan); BEGIN { - maybe_plan(218, "SQL::Translator::Parser::MySQL"); + maybe_plan(228, "SQL::Translator::Parser::MySQL"); SQL::Translator::Parser::MySQL->import('parse'); } @@ -476,7 +476,7 @@ BEGIN { # charset table option # { - my $tr = SQL::Translator->new; + my $tr = SQL::Translator->new(parser_args => {mysql_parser_version => 50003}); my $data = parse($tr, q[ DELIMITER ;; @@ -491,6 +491,58 @@ BEGIN { `op` varchar(255) character set latin1 collate latin1_bin default NULL, `last_modified` timestamp NOT NULL default CURRENT_TIMESTAMP on update CURRENT_TIMESTAMP, ) TYPE=INNODB DEFAULT CHARSET=latin1; + + /*!50001 CREATE ALGORITHM=UNDEFINED */ + /*!50013 DEFINER=`cmdomain`@`localhost` SQL SECURITY DEFINER */ + /*! VIEW `vs_asset` AS + select `a`.`asset_id` AS `asset_id`,`a`.`fq_name` AS `fq_name`, + `cfgmgmt_mig`.`ap_extract_folder`(`a`.`fq_name`) AS `folder_name`, + `cfgmgmt_mig`.`ap_extract_asset`(`a`.`fq_name`) AS `asset_name`, + `a`.`annotation` AS `annotation`,`a`.`asset_type` AS `asset_type`, + `a`.`foreign_asset_id` AS `foreign_asset_id`, + `a`.`foreign_asset_id2` AS `foreign_asset_id2`,`a`.`dateCreated` AS `date_created`, + `a`.`dateModified` AS `date_modified`,`a`.`container_id` AS `container_id`, + `a`.`creator_id` AS `creator_id`,`a`.`modifier_id` AS `modifier_id`, + `m`.`user_id` AS `user_access` + from (`asset` `a` join `M_ACCESS_CONTROL` `m` on((`a`.`acl_id` = `m`.`acl_id`))) */; + DELIMITER ;; + /*!50003 CREATE*/ /*!50020 DEFINER=`cmdomain`@`localhost`*/ /*!50003 FUNCTION `ap_from_millitime_nullable`( millis_since_1970 BIGINT ) RETURNS timestamp + DETERMINISTIC + BEGIN + DECLARE rval TIMESTAMP; + IF ( millis_since_1970 = 0 ) + THEN + SET rval = NULL; + ELSE + SET rval = FROM_UNIXTIME( millis_since_1970 / 1000 ); + END IF; + RETURN rval; + END */;; + /*!50003 CREATE*/ /*!50020 DEFINER=`cmdomain`@`localhost`*/ /*!50003 PROCEDURE `sp_update_security_acl`(IN t_acl_id INTEGER) + BEGIN + DECLARE hasMoreRows BOOL DEFAULT TRUE; + DECLARE t_group_id INT; + DECLARE t_user_id INT ; + DECLARE t_user_name VARCHAR (512) ; + DECLARE t_message VARCHAR (512) ; + + DROP TABLE IF EXISTS group_acl; + DROP TABLE IF EXISTS user_group; + DELETE FROM M_ACCESS_CONTROL WHERE acl_id = t_acl_id; + + CREATE TEMPORARY TABLE group_acl SELECT DISTINCT p.id group_id, d.acl_id acl_id + FROM asset d, acl_entry e, alterpoint_principal p + WHERE d.acl_id = e.acl + AND p.id = e.principal AND d.acl_id = t_acl_id; + + CREATE TEMPORARY TABLE user_group SELECT a.id user_id, a.name user_name, c.id group_id + FROM alterpoint_principal a, groups_for_user b, alterpoint_principal c + WHERE a.id = b.user_ref AND b.elt = c.id; + + INSERT INTO M_ACCESS_CONTROL SELECT DISTINCT group_acl.group_id, group_acl.acl_id, user_group.user_id, user_group.user_name + FROM group_acl, user_group + WHERE group_acl.group_id = user_group.group_id ; + END */;; ] ) or die $tr->error; @@ -530,5 +582,22 @@ BEGIN { ok( !$t1f2->is_nullable, 'Field is not nullable' ); is( $t1f2->default_value, 'CURRENT_TIMESTAMP', 'Field has right default value' ); is( $t1f2->extra('on update'), 'CURRENT_TIMESTAMP', 'Field has right on update qualifier' ); + + my @views = $schema->get_views; + is( scalar @views, 1, 'Right number of views (1)' ); + my $view1 = shift @views; + is( $view1->name, 'vs_asset', 'Found "vs_asset" view' ); + like($view1->sql, qr/ALGORITHM=UNDEFINED/, "Detected algorithm"); + like($view1->sql, qr/vs_asset/, "Detected view vs_asset"); + unlike($view1->sql, qr/cfgmgmt_mig/, "Did not detect cfgmgmt_mig"); + + my @procs = $schema->get_procedures; + is( scalar @procs, 2, 'Right number of procedures (2)' ); + my $proc1 = shift @procs; + is( $proc1->name, 'ap_from_millitime_nullable', 'Found "ap_from_millitime_nullable" procedure' ); + like($proc1->sql, qr/CREATE FUNCTION ap_from_millitime_nullable/, "Detected procedure ap_from_millitime_nullable"); + my $proc2 = shift @procs; + is( $proc2->name, 'sp_update_security_acl', 'Found "sp_update_security_acl" procedure' ); + like($proc2->sql, qr/CREATE PROCEDURE sp_update_security_acl/, "Detected procedure sp_update_security_acl"); }