Skip to content

Commit e4aa635

Browse files
Add option to convert Identity columns to "GENERATED ALWAYS AS IDENTITY" (#150)
* Add option (`use_identity_column`) to convert Identity columns to "GENERATED ALWAYS AS IDENTITY" columns unset the option to use `CREATE SEQUENCE` statements instead. Co-authored-by: alchemistmatt <[email protected]>
1 parent d93f096 commit e4aa635

File tree

2 files changed

+90
-42
lines changed

2 files changed

+90
-42
lines changed

example_conf_file

+1
Original file line numberDiff line numberDiff line change
@@ -31,6 +31,7 @@ keep identifier case=1 # keep case of database objects; comment out to conv
3131
#camelcasetosnake=1 # Uncomment to convert to snake case; comment out to leave names unchanged (or lowercase)
3232
validate constraints = yes # yes, after or no, should the constraints be validated by the dump ? (yes=validate during load, after after the load, no keep invalidated)
3333
#skip citext length check=1 # When defined, do not add a CHECK (char_length()) check for citext fields
34+
use identity column=1 # if set, use identity columns statements ('CREATE GENERATED ALWAYS') instead of creating a dedicated sequence ('CREATE SEQUENCE')
3435

3536
# Incremental job
3637
sort size=10000 # drives the amount of memory and temporary files that will be created by an incremental job

sqlserver2pgsql.pl

+89-42
Original file line numberDiff line numberDiff line change
@@ -53,6 +53,7 @@
5353
our $pforce_ssl;
5454
our $stringtype_unspecified;
5555
our $skip_citext_length_check;
56+
our $use_identity_column;
5657

5758
# Will be set if we detect GIS objects
5859
our $requires_postgis=0;
@@ -109,7 +110,8 @@ sub parse_conf_file
109110
'ignore errors' => 'ignore_errors',
110111
'postgresql force ssl' => 'pforce_ssl',
111112
'stringtype unspecified' => 'stringtype_unspecified',
112-
'skip citext length check' => 'skip_citext_length_check',
113+
'skip citext length check' => 'skip_citext_length_check',
114+
'use identity column' => 'use_identity_column',
113115
);
114116

115117
# Open the conf file or die
@@ -161,6 +163,7 @@ sub set_default_conf_values
161163
$pforce_ssl=0 unless (defined ($pforce_ssl));
162164
$stringtype_unspecified=0 unless (defined ($stringtype_unspecified));
163165
$skip_citext_length_check=0 unless (defined ($skip_citext_length_check));
166+
$use_identity_column=0 unless (defined ($use_identity_column));
164167
}
165168

166169
# Converts numeric(4,0) and similar to int, bigint, smallint
@@ -792,6 +795,11 @@ sub usage
792795
'1' sort all tables. LIST_OF_TABLES gives a comma separated list of
793796
tables to sort in the form 'schema1.table1,schema2.table2'. Cases
794797
are compared insensitively.
798+
-skip_citext_length_check (Default 0)
799+
if set, do not add a CHECK (char_length()) check for citext fields
800+
-use_identity_column (Default 1)
801+
if set, use identity columns statements (GENERATED ALWAYS AS
802+
IDENTITY) instead of creating a dedicated sequence (CREATE SEQUENCE)
795803
796804
Kettle options:
797805
if you are generating for kettle, you must provide connection information.
@@ -2584,35 +2592,63 @@ sub generate_schema
25842592
foreach my $sequence (sort keys %{$refschema->{SEQUENCES}})
25852593
{
25862594
my $seqref = $refschema->{SEQUENCES}->{$sequence};
2587-
print AFTER "CREATE SEQUENCE " . format_identifier($schema) . '.' . format_identifier($sequence);
2588-
if (defined $seqref->{STEP})
2589-
{
2590-
print AFTER " INCREMENT BY ",$seqref->{STEP};
2591-
}
2592-
if (defined $seqref->{MIN})
2593-
{
2594-
print AFTER " MINVALUE ",$seqref->{MIN};
2595-
}
2596-
if (defined $seqref->{MAX})
2597-
{
2598-
print AFTER " MAXVALUE ",$seqref->{MAX};
2599-
}
2600-
if (defined $seqref->{START})
2601-
{
2602-
print AFTER " START WITH ",$seqref->{START};
2603-
}
2604-
if (defined $seqref->{CACHE})
2605-
{
2606-
print AFTER " CACHE ",$seqref->{CACHE};
2607-
}
2608-
if (defined $seqref->{OWNERTABLE})
2609-
{
2610-
print AFTER " OWNED BY ",format_identifier($seqref->{OWNERSCHEMA}),
2611-
'.',format_identifier($seqref->{OWNERTABLE}),
2612-
'.',format_identifier($seqref->{OWNERCOL});
2613-
}
2614-
print AFTER ";\n";
2615-
}
2595+
2596+
if ($use_identity_column and defined $seqref->{OWNERTABLE})
2597+
{
2598+
# Add a statement of the form
2599+
# ALTER TABLE "schema"."table_name" ALTER COLUMN "column_name" ADD GENERATED ALWAYS AS IDENTITY (start 1000);
2600+
2601+
print AFTER "ALTER TABLE " . format_identifier($schema) . '.' . format_identifier($seqref->{OWNERTABLE}) . " ";
2602+
print AFTER "ALTER COLUMN " . format_identifier($seqref->{OWNERCOL}) . " ADD GENERATED ALWAYS AS IDENTITY";
2603+
2604+
if (defined $seqref->{START} or defined $seqref->{STEP})
2605+
{
2606+
print AFTER " (";
2607+
if (defined $seqref->{START})
2608+
{
2609+
print AFTER " START WITH ",$seqref->{START};
2610+
}
2611+
2612+
if (defined $seqref->{STEP})
2613+
{
2614+
print AFTER " INCREMENT BY ",$seqref->{STEP};
2615+
}
2616+
print AFTER ")";
2617+
}
2618+
}
2619+
else
2620+
{
2621+
print AFTER "CREATE SEQUENCE " . format_identifier($schema) . '.' . format_identifier($sequence);
2622+
if (defined $seqref->{STEP})
2623+
{
2624+
print AFTER " INCREMENT BY ",$seqref->{STEP};
2625+
}
2626+
if (defined $seqref->{MIN})
2627+
{
2628+
print AFTER " MINVALUE ",$seqref->{MIN};
2629+
}
2630+
if (defined $seqref->{MAX})
2631+
{
2632+
print AFTER " MAXVALUE ",$seqref->{MAX};
2633+
}
2634+
if (defined $seqref->{START})
2635+
{
2636+
print AFTER " START WITH ",$seqref->{START};
2637+
}
2638+
if (defined $seqref->{CACHE})
2639+
{
2640+
print AFTER " CACHE ",$seqref->{CACHE};
2641+
}
2642+
if (defined $seqref->{OWNERTABLE})
2643+
{
2644+
print AFTER " OWNED BY ",format_identifier($seqref->{OWNERSCHEMA}),
2645+
'.',format_identifier($seqref->{OWNERTABLE}),
2646+
'.',format_identifier($seqref->{OWNERCOL});
2647+
}
2648+
}
2649+
2650+
print AFTER ";\n";
2651+
}
26162652

26172653
# Now PK. We have to go through all tables
26182654
foreach my $table (sort keys %{$refschema->{TABLES}})
@@ -2861,12 +2897,20 @@ sub generate_schema
28612897
. " ALTER COLUMN " . format_identifier($col)
28622898
. " SET DEFAULT " . $default_value . ";\n";
28632899
if ($colref->{DEFAULT}->{UNSURE})
2864-
{
2900+
{
28652901
print UNSURE $definition;
28662902
}
28672903
else
28682904
{
2869-
print AFTER $definition;
2905+
if ($use_identity_column and ($definition =~ /nextval.+_seq/i))
2906+
{
2907+
# Skip this set default item
2908+
}
2909+
else
2910+
{
2911+
print AFTER $definition;
2912+
}
2913+
28702914
}
28712915
}
28722916
}
@@ -2880,6 +2924,7 @@ sub generate_schema
28802924
my $seqref = $refschema->{SEQUENCES}->{$sequence};
28812925
# This may not be an identity. Skip it then
28822926
next unless defined ($seqref->{OWNERCOL});
2927+
next if defined ($use_identity_column);
28832928
print AFTER "select setval('" . format_identifier($schema) . '.'
28842929
. format_identifier($sequence) . "',(select " . ($seqref->{STEP} > 0 ? "max" : "min") . "("
28852930
. format_identifier($seqref->{OWNERCOL}) .") from "
@@ -3112,16 +3157,18 @@ sub resolve_name_conflicts
31123157
"i" => \$case_insensitive,
31133158
"nr" => \$norelabel_dbo,
31143159
"num" => \$convert_numeric_to_int,
3115-
"drop_rowversion" => \$drop_rowversion,
3116-
"relabel_schemas=s" => \$relabel_schemas,
3117-
"keep_identifier_case" => \$keep_identifier_case,
3118-
"camel_to_snake" => \$camel_to_snake,
3119-
"validate_constraints=s" => \$validate_constraints,
3120-
"sort_size=i" => \$sort_size,
3121-
"use_pk_if_possible=s" => \$use_pk_if_possible,
3122-
"ignore_errors" => \$ignore_errors,
3123-
"pforce_ssl" => \$pforce_ssl,
3124-
"stringtype_unspecified" => \$stringtype_unspecified
3160+
"drop_rowversion" => \$drop_rowversion,
3161+
"relabel_schemas=s" => \$relabel_schemas,
3162+
"keep_identifier_case" => \$keep_identifier_case,
3163+
"camel_to_snake" => \$camel_to_snake,
3164+
"validate_constraints=s" => \$validate_constraints,
3165+
"sort_size=i" => \$sort_size,
3166+
"use_pk_if_possible=s" => \$use_pk_if_possible,
3167+
"ignore_errors" => \$ignore_errors,
3168+
"pforce_ssl" => \$pforce_ssl,
3169+
"stringtype_unspecified" => \$stringtype_unspecified,
3170+
"skip_citext_length_check" => \$skip_citext_length_check,
3171+
"use_identity_column" => \$use_identity_column
31253172
);
31263173

31273174
# We don't understand command line or have been asked for usage

0 commit comments

Comments
 (0)