Skip to content
Projects
Groups
Snippets
Help
This project
Loading...
Sign in / Register
Toggle navigation
bugzilla
Project
Project
Details
Activity
Cycle Analytics
Repository
Repository
Files
Commits
Branches
Tags
Contributors
Graph
Compare
Charts
Issues
0
Issues
0
List
Board
Labels
Milestones
Merge Requests
0
Merge Requests
0
CI / CD
CI / CD
Pipelines
Jobs
Schedules
Charts
Wiki
Wiki
Members
Members
Collapse sidebar
Close sidebar
Activity
Graph
Charts
Create a new issue
Jobs
Commits
Issue Boards
Open sidebar
etersoft
bugzilla
Commits
a4b66874
Commit
a4b66874
authored
Dec 13, 2007
by
mkanat%bugzilla.org
Browse files
Options
Browse Files
Download
Email Patches
Plain Diff
Bug 408032: [Oracle] Make bzdbcopy.pl work with Oracle
Patch By Max Kanat-Alexander <mkanat@bugzilla.org> (module owner) a=mkanat
parent
5c779ad5
Hide whitespace changes
Inline
Side-by-side
Showing
8 changed files
with
146 additions
and
37 deletions
+146
-37
DB.pm
Bugzilla/DB.pm
+31
-0
Oracle.pm
Bugzilla/DB/Oracle.pm
+23
-0
Schema.pm
Bugzilla/DB/Schema.pm
+3
-3
Mysql.pm
Bugzilla/DB/Schema/Mysql.pm
+3
-3
Oracle.pm
Bugzilla/DB/Schema/Oracle.pm
+21
-8
Util.pm
Bugzilla/Install/Util.pm
+1
-1
bzdbcopy.pl
contrib/bzdbcopy.pl
+61
-22
messages.html.tmpl
template/en/default/global/messages.html.tmpl
+3
-0
No files found.
Bugzilla/DB.pm
View file @
a4b66874
...
@@ -504,6 +504,19 @@ sub bz_setup_foreign_keys {
...
@@ -504,6 +504,19 @@ sub bz_setup_foreign_keys {
}
}
}
}
# This is used by contrib/bzdbcopy.pl, mostly.
sub
bz_drop_foreign_keys
{
my
(
$self
)
=
@_
;
my
@tables
=
$self
->
_bz_real_schema
->
get_table_list
();
foreach
my
$table
(
@tables
)
{
my
@columns
=
$self
->
_bz_real_schema
->
get_table_columns
(
$table
);
foreach
my
$column
(
@columns
)
{
$self
->
bz_drop_fk
(
$table
,
$column
);
}
}
}
#####################################################################
#####################################################################
# Schema Modification Methods
# Schema Modification Methods
#####################################################################
#####################################################################
...
@@ -749,6 +762,24 @@ sub bz_drop_column {
...
@@ -749,6 +762,24 @@ sub bz_drop_column {
}
}
}
}
sub
bz_drop_fk
{
my
(
$self
,
$table
,
$column
)
=
@_
;
my
$col_def
=
$self
->
bz_column_info
(
$table
,
$column
);
if
(
$col_def
&&
exists
$col_def
->
{
REFERENCES
})
{
my
$def
=
$col_def
->
{
REFERENCES
};
print
get_text
(
'install_fk_drop'
,
{
table
=>
$table
,
column
=>
$column
,
fk
=>
$def
})
.
"\n"
if
Bugzilla
->
usage_mode
==
USAGE_MODE_CMDLINE
;
my
@sql
=
$self
->
_bz_real_schema
->
get_drop_fk_sql
(
$table
,
$column
,
$def
);
$self
->
do
(
$_
)
foreach
@sql
;
delete
$col_def
->
{
REFERENCES
};
$self
->
_bz_real_schema
->
set_column
(
$table
,
$column
,
$col_def
);
$self
->
_bz_store_real_schema
;
}
}
sub
bz_drop_index
{
sub
bz_drop_index
{
my
(
$self
,
$table
,
$name
)
=
@_
;
my
(
$self
,
$table
,
$name
)
=
@_
;
...
...
Bugzilla/DB/Oracle.pm
View file @
a4b66874
...
@@ -406,7 +406,30 @@ sub quote_identifier {
...
@@ -406,7 +406,30 @@ sub quote_identifier {
return
$id
;
return
$id
;
}
}
#####################################################################
# Protected "Real Database" Schema Information Methods
#####################################################################
sub
bz_table_columns_real
{
my
(
$self
,
$table
)
=
@_
;
$table
=
uc
(
$table
);
my
@cols
=
$self
->
SUPER::
bz_table_columns_real
(
$table
);
return
map
{
lc
(
$_
)
}
@cols
;
}
sub
bz_table_list_real
{
my
(
$self
)
=
@_
;
# Oracle only accepts the username in uppercase.
my
$db_user
=
uc
(
Bugzilla
->
localconfig
->
{
db_user
});
my
$table_sth
=
$self
->
table_info
(
undef
,
$db_user
,
undef
,
"TABLE"
);
my
@tables
=
@
{
$self
->
selectcol_arrayref
(
$table_sth
,
{
Columns
=>
[
3
]
})};
# Oracle returns uppercase table names, but Bugzilla expects lowercase
# names.
@tables
=
map
{
lc
(
$_
)
}
@tables
;
# Oracle has certain tables that start with DR$_IDX.
@tables
=
grep
{
$_
!~
/^dr\$/
}
@tables
;
return
@tables
;
}
#####################################################################
#####################################################################
# Custom Database Setup
# Custom Database Setup
...
...
Bugzilla/DB/Schema.pm
View file @
a4b66874
...
@@ -1533,9 +1533,9 @@ sub get_add_fk_sql {
...
@@ -1533,9 +1533,9 @@ sub get_add_fk_sql {
return
(
"ALTER TABLE $table ADD $fk_string"
);
return
(
"ALTER TABLE $table ADD $fk_string"
);
}
}
sub
_
get_drop_fk_sql
{
sub
get_drop_fk_sql
{
my
(
$self
,
$table
,
$column
,
$
old_def
)
=
@_
;
my
(
$self
,
$table
,
$column
,
$
references
)
=
@_
;
my
$fk_name
=
$self
->
_get_fk_name
(
$table
,
$column
,
$
old_def
->
{
REFERENCES
}
);
my
$fk_name
=
$self
->
_get_fk_name
(
$table
,
$column
,
$
references
);
return
(
"ALTER TABLE $table DROP CONSTRAINT $fk_name"
);
return
(
"ALTER TABLE $table DROP CONSTRAINT $fk_name"
);
}
}
...
...
Bugzilla/DB/Schema/Mysql.pm
View file @
a4b66874
...
@@ -193,9 +193,9 @@ sub get_alter_column_ddl {
...
@@ -193,9 +193,9 @@ sub get_alter_column_ddl {
return
@statements
;
return
@statements
;
}
}
sub
_
get_drop_fk_sql
{
sub
get_drop_fk_sql
{
my
(
$self
,
$table
,
$column
,
$
old_def
)
=
@_
;
my
(
$self
,
$table
,
$column
,
$
references
)
=
@_
;
my
$fk_name
=
$self
->
_get_fk_name
(
$table
,
$column
,
$
old_def
->
{
REFERENCES
}
);
my
$fk_name
=
$self
->
_get_fk_name
(
$table
,
$column
,
$
references
);
my
@sql
=
(
"ALTER TABLE $table DROP FOREIGN KEY $fk_name"
);
my
@sql
=
(
"ALTER TABLE $table DROP FOREIGN KEY $fk_name"
);
my
$dbh
=
Bugzilla
->
dbh
;
my
$dbh
=
Bugzilla
->
dbh
;
...
...
Bugzilla/DB/Schema/Oracle.pm
View file @
a4b66874
...
@@ -93,7 +93,7 @@ sub get_table_ddl {
...
@@ -93,7 +93,7 @@ sub get_table_ddl {
}
}
# Create sequences and triggers to emulate SERIAL datatypes.
# Create sequences and triggers to emulate SERIAL datatypes.
if
(
$field_info
->
{
TYPE
}
=~
/SERIAL/i
)
{
if
(
$field_info
->
{
TYPE
}
=~
/SERIAL/i
)
{
push
(
@ddl
,
_get_create_seq_ddl
(
$table
,
$field_name
));
push
(
@ddl
,
$self
->
_get_create_seq_ddl
(
$table
,
$field_name
));
}
}
}
}
return
@ddl
;
return
@ddl
;
...
@@ -140,17 +140,17 @@ sub get_fk_ddl {
...
@@ -140,17 +140,17 @@ sub get_fk_ddl {
$fk_string
=
$fk_string
.
" ON DELETE $delete"
if
$delete
;
$fk_string
=
$fk_string
.
" ON DELETE $delete"
if
$delete
;
if
(
$update
=~
/CASCADE/i
){
if
(
$update
=~
/CASCADE/i
){
my
$tr_str
=
"CREATE OR REPLACE TRIGGER
"
.
$table
.
"_uc
"
my
$tr_str
=
"CREATE OR REPLACE TRIGGER
${fk_name}_UC
"
.
" AFTER UPDATE ON "
.
$table
.
" AFTER UPDATE ON "
.
$table
.
" REFERENCING "
.
" REFERENCING "
.
" NEW AS NEW "
.
" NEW AS NEW "
.
" OLD AS OLD "
.
" OLD AS OLD "
.
" FOR EACH ROW "
.
" FOR EACH ROW "
.
" BEGIN "
.
" BEGIN "
.
" UPDATE
"
.
$to_table
.
" UPDATE
$to_table"
.
"
SET "
.
$to_column
.
" = :NEW."
.
$column
.
"
SET $to_column = :NEW.$column"
.
"
WHERE "
.
$to_column
.
" = :OLD."
.
$column
.
"
;"
.
"
WHERE $to_column = :OLD.$column
;"
.
" END
"
.
$table
.
"_uc
;"
;
.
" END
${fk_name}_UC
;"
;
my
$dbh
=
Bugzilla
->
dbh
;
my
$dbh
=
Bugzilla
->
dbh
;
$dbh
->
do
(
$tr_str
);
$dbh
->
do
(
$tr_str
);
}
}
...
@@ -158,6 +158,18 @@ sub get_fk_ddl {
...
@@ -158,6 +158,18 @@ sub get_fk_ddl {
return
$fk_string
;
return
$fk_string
;
}
}
sub
get_drop_fk_sql
{
my
$self
=
shift
;
my
(
$table
,
$column
,
$references
)
=
@_
;
my
$fk_name
=
$self
->
_get_fk_name
(
@_
);
my
@sql
;
if
(
!
$references
->
{
UPDATE
}
||
$references
->
{
UPDATE
}
=~
/CASCADE/i
)
{
push
(
@sql
,
"DROP TRIGGER ${fk_name}_uc"
);
}
push
(
@sql
,
$self
->
SUPER::
get_drop_fk_sql
(
@_
));
return
@sql
;
}
sub
_get_fk_name
{
sub
_get_fk_name
{
my
(
$self
,
$table
,
$column
,
$references
)
=
@_
;
my
(
$self
,
$table
,
$column
,
$references
)
=
@_
;
my
$to_table
=
$references
->
{
TABLE
};
my
$to_table
=
$references
->
{
TABLE
};
...
@@ -185,12 +197,13 @@ sub _get_notnull_trigger_ddl {
...
@@ -185,12 +197,13 @@ sub _get_notnull_trigger_ddl {
}
}
sub
_get_create_seq_ddl
{
sub
_get_create_seq_ddl
{
my
(
$table
,
$column
)
=
@_
;
my
(
$self
,
$table
,
$column
,
$start_with
)
=
@_
;
$start_with
||=
1
;
my
@ddl
;
my
@ddl
;
my
$seq_name
=
"${table}_${column}_SEQ"
;
my
$seq_name
=
"${table}_${column}_SEQ"
;
my
$seq_sql
=
"CREATE SEQUENCE $seq_name "
my
$seq_sql
=
"CREATE SEQUENCE $seq_name "
.
" INCREMENT BY 1 "
.
" INCREMENT BY 1 "
.
" START WITH
1
"
.
" START WITH
$start_with
"
.
" NOMAXVALUE "
.
" NOMAXVALUE "
.
" NOCYCLE "
.
" NOCYCLE "
.
" NOCACHE"
;
.
" NOCACHE"
;
...
...
Bugzilla/Install/Util.pm
View file @
a4b66874
...
@@ -80,7 +80,7 @@ sub indicate_progress {
...
@@ -80,7 +80,7 @@ sub indicate_progress {
my
$every
=
$params
->
{
every
}
||
1
;
my
$every
=
$params
->
{
every
}
||
1
;
print
"."
if
!
(
$current
%
$every
);
print
"."
if
!
(
$current
%
$every
);
if
(
$current
%
(
$every
*
60
)
==
0
)
{
if
(
$current
==
$total
||
$current
%
(
$every
*
60
)
==
0
)
{
print
"$current/$total ("
.
int
(
$current
*
100
/
$total
)
.
"%)\n"
;
print
"$current/$total ("
.
int
(
$current
*
100
/
$total
)
.
"%)\n"
;
}
}
}
}
...
...
contrib/bzdbcopy.pl
View file @
a4b66874
...
@@ -21,7 +21,9 @@
...
@@ -21,7 +21,9 @@
use
strict
;
use
strict
;
use
lib
qw(. lib)
;
use
lib
qw(. lib)
;
use
Bugzilla
;
use
Bugzilla
;
use
Bugzilla::
Constants
;
use
Bugzilla::
DB
;
use
Bugzilla::
DB
;
use
Bugzilla::Install::
Util
qw(indicate_progress)
;
use
Bugzilla::
Util
;
use
Bugzilla::
Util
;
#####################################################################
#####################################################################
...
@@ -33,25 +35,29 @@ use constant SOURCE_DB_TYPE => 'Mysql';
...
@@ -33,25 +35,29 @@ use constant SOURCE_DB_TYPE => 'Mysql';
use
constant
SOURCE_DB_NAME
=>
'bugs'
;
use
constant
SOURCE_DB_NAME
=>
'bugs'
;
use
constant
SOURCE_DB_USER
=>
'bugs'
;
use
constant
SOURCE_DB_USER
=>
'bugs'
;
use
constant
SOURCE_DB_PASSWORD
=>
''
;
use
constant
SOURCE_DB_PASSWORD
=>
''
;
use
constant
SOURCE_DB_HOST
=>
'localhost'
;
# Settings for the 'Target' DB that you are copying to.
# Settings for the 'Target' DB that you are copying to.
use
constant
TARGET_DB_TYPE
=>
'Pg'
;
use
constant
TARGET_DB_TYPE
=>
'Pg'
;
use
constant
TARGET_DB_NAME
=>
'bugs'
;
use
constant
TARGET_DB_NAME
=>
'bugs'
;
use
constant
TARGET_DB_USER
=>
'bugs'
;
use
constant
TARGET_DB_USER
=>
'bugs'
;
use
constant
TARGET_DB_PASSWORD
=>
''
;
use
constant
TARGET_DB_PASSWORD
=>
''
;
use
constant
TARGET_DB_HOST
=>
'localhost'
;
#####################################################################
#####################################################################
# MAIN SCRIPT
# MAIN SCRIPT
#####################################################################
#####################################################################
Bugzilla
->
usage_mode
(
USAGE_MODE_CMDLINE
);
print
"Connecting to the '"
.
SOURCE_DB_NAME
.
"' source database on "
print
"Connecting to the '"
.
SOURCE_DB_NAME
.
"' source database on "
.
SOURCE_DB_TYPE
.
"...\n"
;
.
SOURCE_DB_TYPE
.
"...\n"
;
my
$source_db
=
Bugzilla::DB::
_connect
(
SOURCE_DB_TYPE
,
'localhost'
,
my
$source_db
=
Bugzilla::DB::
_connect
(
SOURCE_DB_TYPE
,
SOURCE_DB_HOST
,
SOURCE_DB_NAME
,
undef
,
undef
,
SOURCE_DB_USER
,
SOURCE_DB_PASSWORD
);
SOURCE_DB_NAME
,
undef
,
undef
,
SOURCE_DB_USER
,
SOURCE_DB_PASSWORD
);
print
"Connecting to the '"
.
TARGET_DB_NAME
.
"' target database on "
print
"Connecting to the '"
.
TARGET_DB_NAME
.
"' target database on "
.
TARGET_DB_TYPE
.
"...\n"
;
.
TARGET_DB_TYPE
.
"...\n"
;
my
$target_db
=
Bugzilla::DB::
_connect
(
TARGET_DB_TYPE
,
'localhost'
,
my
$target_db
=
Bugzilla::DB::
_connect
(
TARGET_DB_TYPE
,
TARGET_DB_HOST
,
TARGET_DB_NAME
,
undef
,
undef
,
TARGET_DB_USER
,
TARGET_DB_PASSWORD
);
TARGET_DB_NAME
,
undef
,
undef
,
TARGET_DB_USER
,
TARGET_DB_PASSWORD
);
my
$ident_char
=
$target_db
->
get_info
(
29
);
# SQL_IDENTIFIER_QUOTE_CHAR
my
$ident_char
=
$target_db
->
get_info
(
29
);
# SQL_IDENTIFIER_QUOTE_CHAR
...
@@ -65,11 +71,12 @@ my @table_list = $target_db->bz_table_list_real();
...
@@ -65,11 +71,12 @@ my @table_list = $target_db->bz_table_list_real();
my
$bz_schema_location
=
lsearch
(
\
@table_list
,
'bz_schema'
);
my
$bz_schema_location
=
lsearch
(
\
@table_list
,
'bz_schema'
);
splice
(
@table_list
,
$bz_schema_location
,
1
)
if
$bz_schema_location
>
0
;
splice
(
@table_list
,
$bz_schema_location
,
1
)
if
$bz_schema_location
>
0
;
# We turn off autocommit on the target DB, because we're doing so
# Instead of figuring out some fancy algorithm to insert data in the right
# much copying.
# order and not break FK integrity, we just drop them all.
$target_db
->
{
AutoCommit
}
=
0
;
$target_db
->
bz_drop_foreign_keys
();
$target_db
->
{
AutoCommit
}
==
0
# We start a transaction on the target DB, which helps when we're doing
||
warn
"Failed to disable autocommit on "
.
TARGET_DB_TYPE
;
# so many inserts.
$target_db
->
bz_start_transaction
();
foreach
my
$table
(
@table_list
)
{
foreach
my
$table
(
@table_list
)
{
my
@serial_cols
;
my
@serial_cols
;
print
"Reading data from the source '$table' table on "
print
"Reading data from the source '$table' table on "
...
@@ -94,9 +101,25 @@ foreach my $table (@table_list) {
...
@@ -94,9 +101,25 @@ foreach my $table (@table_list) {
print
"Clearing out the target '$table' table on "
print
"Clearing out the target '$table' table on "
.
TARGET_DB_TYPE
.
"...\n"
;
.
TARGET_DB_TYPE
.
"...\n"
;
$target_db
->
do
(
"DELETE FROM $table"
);
$target_db
->
do
(
"DELETE FROM $table"
);
# Oracle doesn't like us manually inserting into tables that have
# auto-increment PKs set, because of the way we made auto-increment
# fields work.
if
(
$target_db
->
isa
(
'Bugzilla::DB::Oracle'
))
{
foreach
my
$column
(
@table_columns
)
{
my
$col_info
=
$source_db
->
bz_column_info
(
$table
,
$column
);
if
(
$col_info
&&
$col_info
->
{
TYPE
}
=~
/SERIAL/i
)
{
print
"Dropping the sequence + trigger on $table.$column...\n"
;
$target_db
->
do
(
"DROP TRIGGER ${table}_${column}_TR"
);
$target_db
->
do
(
"DROP SEQUENCE ${table}_${column}_SEQ"
);
}
}
}
print
"Writing data to the target '$table' table on "
print
"Writing data to the target '$table' table on "
.
TARGET_DB_TYPE
.
"..."
;
.
TARGET_DB_TYPE
.
"...\n"
;
my
$count
=
0
;
my
$total
=
scalar
@$data_in
;
foreach
my
$row
(
@$data_in
)
{
foreach
my
$row
(
@$data_in
)
{
# Each column needs to be bound separately, because
# Each column needs to be bound separately, because
# many columns need to be dealt with specially.
# many columns need to be dealt with specially.
...
@@ -144,24 +167,39 @@ foreach my $table (@table_list) {
...
@@ -144,24 +167,39 @@ foreach my $table (@table_list) {
}
}
$insert_sth
->
execute
();
$insert_sth
->
execute
();
$count
++
;
indicate_progress
({
current
=>
$count
,
total
=>
$total
,
every
=>
100
});
}
}
# PostgreSQL doesn't like it when you insert values into
# For some DBs, we have to do clever things with auto-increment fields.
# a serial field; it doesn't increment the counter
foreach
my
$column
(
@table_columns
)
{
# automatically.
next
if
$target_db
->
isa
(
'Bugzilla::DB::Mysql'
);
if
(
$target_db
->
isa
(
'Bugzilla::DB::Pg'
))
{
my
$col_info
=
$source_db
->
bz_column_info
(
$table
,
$column
);
foreach
my
$column
(
@table_columns
)
{
if
(
$col_info
&&
$col_info
->
{
TYPE
}
=~
/SERIAL/i
)
{
my
$col_info
=
$source_db
->
bz_column_info
(
$table
,
$column
);
my
(
$max_val
)
=
$target_db
->
selectrow_array
(
if
(
$col_info
&&
$col_info
->
{
TYPE
}
=~
/SERIAL/i
)
{
# Set the sequence to the current max value + 1.
my
(
$max_val
)
=
$target_db
->
selectrow_array
(
"SELECT MAX($column) FROM $table"
);
"SELECT MAX($column) FROM $table"
);
$max_val
=
0
if
!
defined
$max_val
;
# Set the sequence to the current max value + 1.
$max_val
++
;
$max_val
=
0
if
!
defined
$max_val
;
print
"\nSetting the next value for $table.$column to $max_val."
;
$max_val
++
;
print
"\nSetting the next value for $table.$column to $max_val."
;
if
(
$target_db
->
isa
(
'Bugzilla::DB::Pg'
))
{
# PostgreSQL doesn't like it when you insert values into
# a serial field; it doesn't increment the counter
# automatically.
$target_db
->
do
(
"SELECT pg_catalog.setval
$target_db
->
do
(
"SELECT pg_catalog.setval
('${table}_${column}_seq', $max_val, false)"
);
('${table}_${column}_seq', $max_val, false)"
);
}
}
elsif
(
$target_db
->
isa
(
'Bugzilla::DB::Oracle'
))
{
# Oracle increments the counter on every insert, and *always*
# sets the field, even if you gave it a value. So if there
# were already rows in the target DB (like the default rows
# created by checksetup), you'll get crazy values in your
# id columns. So we just dropped the sequences above and
# we re-create them here, starting with the right number.
my
@sql
=
$target_db
->
_bz_real_schema
->
_get_create_seq_ddl
(
$table
,
$column
,
$max_val
);
$target_db
->
do
(
$_
)
foreach
@sql
;
}
}
}
}
}
...
@@ -169,9 +207,10 @@ foreach my $table (@table_list) {
...
@@ -169,9 +207,10 @@ foreach my $table (@table_list) {
}
}
print
"Committing changes to the target database...\n"
;
print
"Committing changes to the target database...\n"
;
$target_db
->
commit
;
$target_db
->
bz_commit_transaction
();
$target_db
->
bz_setup_foreign_keys
();
print
"All done! Make sure to run checksetup on the new DB.\n"
;
print
"All done! Make sure to run checksetup
.pl
on the new DB.\n"
;
$source_db
->
disconnect
;
$source_db
->
disconnect
;
$target_db
->
disconnect
;
$target_db
->
disconnect
;
...
...
template/en/default/global/messages.html.tmpl
View file @
a4b66874
...
@@ -388,6 +388,9 @@
...
@@ -388,6 +388,9 @@
[% ELSIF message_tag == "install_fk_add" %]
[% ELSIF message_tag == "install_fk_add" %]
Adding foreign key: [% table FILTER html %].[% column FILTER html %] -> [% fk.TABLE FILTER html %].[% fk.COLUMN FILTER html %]...
Adding foreign key: [% table FILTER html %].[% column FILTER html %] -> [% fk.TABLE FILTER html %].[% fk.COLUMN FILTER html %]...
[% ELSIF message_tag == "install_fk_drop" %]
Dropping foreign key: [% table FILTER html %].[% column FILTER html %] -> [% fk.TABLE FILTER html %].[% fk.COLUMN FILTER html %]...
[% ELSIF message_tag == "install_group_create" %]
[% ELSIF message_tag == "install_group_create" %]
Creating group [% name FILTER html %]...
Creating group [% name FILTER html %]...
...
...
Write
Preview
Markdown
is supported
0%
Try again
or
attach a new file
Attach a file
Cancel
You are about to add
0
people
to the discussion. Proceed with caution.
Finish editing this message first!
Cancel
Please
register
or
sign in
to comment