Compare commits

...

10 commits

Author SHA1 Message Date
Bradley M. Kuhn
8f54ebb54c Big Postal Address Change — First steps toward new fields.
These are various changes to support the changes to the postal
address table to include split-out fields for parts of the address
instead of just the formatted_address field.  The changes herein are
not comprehensive to solve all the problems and issues associated
with this update, but they are enough changes to get most daily
operations with the database more-or-less working.
2022-12-16 11:36:15 -08:00
Bradley M. Kuhn
aab0b132b2 Return additional values on getPostalAddress 2022-12-08 08:12:43 -08:00
Bradley M. Kuhn
0219fc3dee Include notes in output of requests; better find output formatting 2022-11-21 17:31:34 -08:00
Bradley M. Kuhn
ca8348d84b Rework various aspects of shirt label printing
The primary change here is to add output such that we can get CSV
output that can be later used in post-processing to upload the data
to  third-party shipping services.

Various other changes are present as well, including changes to the
logic related to which t-shirt to give when no specific type is
requested.
2022-11-21 17:31:17 -08:00
Bradley M. Kuhn
4a6ad06ebb Switch to using entity instead of donor_name in views.
This is less confusing because `entity` is used elsewhere.
2022-11-21 17:31:07 -08:00
Bradley M. Kuhn
3fa1f004d3 Two new views and related triggers for email/post address insert
UserOperation_add_postal_for_donor_with_none, UserOperation_email_add_when_none
2022-11-21 15:25:00 -08:00
Bradley M. Kuhn
d0b7f15f2a Insert operation for UserOperation_donor_update view 2022-11-21 15:24:27 -08:00
Bradley M. Kuhn
225eb13674 Add trigger to allow update of notes as well on contact_settings. 2022-11-21 11:39:23 -08:00
Bradley M. Kuhn
deb31e9c18 Use OLD.donor_id, as NEW.donor_id will actually be NULL probably. 2022-11-21 11:39:05 -08:00
Bradley M. Kuhn
d505f69f00 Add new style as an option for t-shirts. 2022-11-13 15:01:31 -08:00
4 changed files with 400 additions and 212 deletions

View file

@ -403,6 +403,8 @@ returned; it means the preferred email address wasn't selected for some reason.
sub setPreferredPostalAddress($$$) {
my($self, $donorId, $postalAddress) = @_;
die "Postal address stuff not fixed yet";
die "setPreferredPostalAddress: invalid supporter id, $donorId" unless $self->_verifyId($donorId);
die "setPreferredPostalAddress: email address not defined" unless defined $postalAddress;
@ -495,15 +497,9 @@ Arguments:
Valid supporter id number currently in the database. die() will occur if
the id number is not in the database already as a supporter id.
=item $postalAddress
Scalar string that contains an postalAddress. undef is returned if the
postal address is not already in the database for this supporter.
=back
Returns the postal_address_id of the preferred postal address. undef can be
Returns the of the preferred postal address. undef can be
returned; it means the preferred postal address wasn't selected for some reason.
=cut
@ -511,21 +507,22 @@ returned; it means the preferred postal address wasn't selected for some reason.
sub getPreferredPostalAddress($$) {
my($self, $donorId) = @_;
die "setPreferredPostalAddress: invalid supporter id, $donorId" unless $self->_verifyId($donorId);
die "getPreferredPostalAddress: invalid supporter id, $donorId" unless $self->_verifyId($donorId);
my $ems = $self->dbh()->selectall_hashref("SELECT formatted_address FROM postal_address em, donor_postal_address_mapping sem " .
"WHERE preferred AND sem.postal_address_id = em.id AND " .
"sem.donor_id = " . $self->dbh->quote($donorId, 'SQL_INTEGER'),
'formatted_address');
my $ems = $self->dbh()->selectall_hashref("SELECT pa.*, at.name as type, map.date_valid_from, map.date_valid_to " .
"FROM donor_postal_address_mapping map, address_type at, postal_address pa " .
"WHERE at.id = map.type_id AND pa.id = map.postal_address_id AND " .
"map.date_valid_to is NULL AND " .
"map.donor_id = " . $self->dbh->quote($donorId, 'SQL_INTEGER'),
'id');
my $rowCount = scalar keys %{$ems};
die "setPreferredPostalAddress: DATABASE INTEGRITY ERROR: more than one postal address is preferred for supporter, \"$donorId\""
die "getPreferredPostalAddress: DATABASE INTEGRITY ERROR: more than one postal address is preferred for supporter, \"$donorId\""
if $rowCount > 1;
if ($rowCount != 1) {
return undef;
} else {
my ($postalAddress) = keys %$ems;
return $postalAddress;
return $ems;
}
}
######################################################################
@ -716,11 +713,11 @@ Returns the id value of the postal_address table entry.
=cut
sub addPostalAddress($$$$;$) {
my($self, $id, $formattedPostalAddress, $addressType, $dateEncountered) = @_;
my($self, $donorId, $postalFields, $addressType, $dateEncountered) = @_;
die "addPostalAddress: invalid id, $id" unless $self->_verifyId($id);
die "addPostalAddress: the formatted postal address must be defined"
unless defined $formattedPostalAddress;
die "addPostalAddress: invalid id, $donorId" unless $self->_verifyId($donorId);
die "addPostalAddress: the postalFields must be provided and must be a hash ref"
unless defined $postalFields and ref $postalFields eq 'HASH';
$self->_beginWork();
@ -734,30 +731,35 @@ sub addPostalAddress($$$$;$) {
$self->_rollback();
die $@ if $@;
}
my $insertStr = "INSERT INTO postal_address(formatted_address, type_id, date_encountered)" .
"VALUES( ?, ?, ";
my $sth;
if (defined $dateEncountered) {
$insertStr .= "?)";
$sth = $self->dbh->prepare($insertStr);
$sth->execute($formattedPostalAddress, $addressTypeId, $dateEncountered);
} else {
$insertStr .= "date('now'))";
$sth = $self->dbh->prepare($insertStr);
$sth->execute($formattedPostalAddress, $addressTypeId);
}
my $addressId = $self->dbh->last_insert_id("","","","");
my $insertPostalStr = <<INSERT_IT
INSERT INTO postal_address(first_name, middle_name, last_name, organization, address_1, address_2,
address_3, city, state_province_or_region, postcode, country)
VALUES( ?, ?, ?, ?, ?, ?,
?, ?, ?, ?, ?)
INSERT_IT
;
my $sth = $self->dbh->prepare($insertPostalStr);
$dateEncountered = "date('now')" if not defined $dateEncountered;
$sth->execute($postalFields->{first_name}, $postalFields->{middle_name}, $postalFields->{last_name},
$postalFields->{organization}, $postalFields->{address_1},
$postalFields->{address_2}, $postalFields->{address_3},
$postalFields->{city}, $postalFields->{state_province_or_region},
$postalFields->{postcode}, $postalFields->{country});
my $newAddressId = $self->dbh->last_insert_id("","","","");
$sth->finish();
$sth = $self->dbh->prepare("UPDATE donor_postal_address_mapping SET date_valid_to = ? " .
"WHERE date_valid_to is NULL AND donor_id = " . $self->dbh->quote($donorId, 'SQL_INTEGER'));
$sth->execute($dateEncountered);
$sth->finish();
$sth = $self->dbh->prepare("INSERT INTO donor_postal_address_mapping" .
"(donor_id, postal_address_id) " .
"VALUES( ?, ?)");
$sth->execute($id, $addressId);
"(donor_id, postal_address_id, type_id, date_valid_from) " .
"VALUES( ?, ?, ?, ?)");
$sth->execute($donorId, $newAddressId, $addressTypeId, $dateEncountered);
$sth->finish();
$self->_commit();
return $addressId;
return $newAddressId;
}
######################################################################
@ -772,13 +774,12 @@ Arguments:
Valid supporter id number currently in the database. die() will occur if
the id number is not in the database already as a supporter id.
=item $formattedPostalAddress
Scalar string that contains a multi-line, fully formatted, postal address.
=back
Returns the id value of the postal_address table entry.
Returns a hash with the postal_address records for the donor with id, $id.
Also returns keys of type, and date_valid_from and date_valid_to from the
donor_postal_address_mapping table.
=cut
@ -787,12 +788,12 @@ sub getPostalAddresses($) {
die "addPostalAddress: invalid id, $id" unless $self->_verifyId($id);
my $val = $self->dbh()->selectall_hashref("SELECT pa.formatted_address, at.name, pa.date_encountered, pa.id " .
my $val = $self->dbh()->selectall_hashref("SELECT pa.*, at.name as type, map.date_valid_from, map.date_valid_to " .
"FROM donor_postal_address_mapping map, address_type at, postal_address pa " .
"WHERE at.id = pa.type_id AND pa.id = map.postal_address_id AND " .
"WHERE at.id = map.type_id AND pa.id = map.postal_address_id AND " .
"map.donor_id = " . $self->dbh->quote($id, 'SQL_INTEGER'),
'formatted_address');
foreach my $key (keys %{$val}) { delete $val->{$key}{formatted_address}; }
'id');
foreach my $key (keys %{$val}) { delete $val->{$key}{id}; }
return %{$val};
}
@ -821,13 +822,15 @@ various concerns it might have about determining the best postal address.
sub getBestPostalAddress($) {
my($self, $id) = @_;
die "Postal address stuff not fixed yet";
die "getBestPostalAddress: invalid id, $id" unless $self->_verifyId($id);
my $pref = $self->getPreferredPostalAddress($id);
my $entries = $self->dbh()->selectall_hashref("SELECT pa.id, pa.formatted_address, at.name, pa.date_encountered " .
"FROM donor_postal_address_mapping map, address_type at, postal_address pa " .
"WHERE at.id = pa.type_id AND pa.id = map.postal_address_id AND " .
"WHERE at.id = map.type_id AND pa.id = map.postal_address_id AND " .
"(pa.invalid is NULL OR pa.invalid != 1) " .
"AND map.donor_id = " . $self->dbh->quote($id, 'SQL_INTEGER'),
'id');

View file

@ -68,11 +68,15 @@ foreach my $id (@supporterIds) {
print "\n NO POSTAL ADDRESSES.\n";
} else {
print "\n Postal Addresses:\n";
foreach my $address (keys %postalAddresses) {
print " PREFERRED FOLLOWS:\n" if (defined $preferredPostal) and $address eq $preferredPostal;
print " Encountered $postalAddresses{$address}{id} on $postalAddresses{$address}{date_encountered} via $postalAddresses{$address}{name}\n";
foreach my $addrLine (split("\n", $address)) {
print " $addrLine\n";
foreach my $addrID (sort
{ $postalAddresses{$a}{date_valid_from} cmp $postalAddresses{$b}{date_valid_from} or
$postalAddresses{$a}{date_valid_to} cmp $postalAddresses{$b}{date_valid_to};
} keys %postalAddresses) {
print " Address $addrID, found in $postalAddresses{$addrID}{type}, valid from $postalAddresses{$addrID}{date_valid_from} until ",
(not defined $postalAddresses{$addrID}{date_valid_to}) ? "RIGHT NOW " : $postalAddresses{$addrID}{date_valid_to}, ":\n";
foreach my $key (qw/first_name middle_name last_name organization address_1 address_2 address_3 city
state_province_or_region postcode country/) {
print " $key: $postalAddresses{$addrID}{$key}\n" if (defined $postalAddresses{$addrID}{$key});
}
}
}
@ -82,22 +86,20 @@ foreach my $id (@supporterIds) {
print " Request $req->{requestId} of $req->{requestType}";
print "($req->{requestConfiguration})" if defined $req->{requestConfiguration};
print " made on $req->{requestDate}";
if (not defined $req->{fulfillDate}) {
print "\n";
} else {
if (defined $req->{fulfillDate}) {
print "...\n fulfilled on $req->{fulfillDate}";
print "...\n by: $req->{fulfilledBy}" if defined $req->{fulfilledBy};
print "...\n via: $req->{fulfilledVia}" if defined $req->{fulfilledVia};
}
if (not defined $req->{holdDate} ) {
print "\n";
} else {
if (defined $req->{holdDate} ) {
print "...\n put on hold on $req->{holdDate} by $req->{holder}";
print "...\n release on: $req->{holdReleaseDate}" if defined $req->{holdReleaseDate};
print "...\n on hold because: $req->{heldBecause}\n" if defined $req->{heldBecause};
print "...\n on hold because: $req->{heldBecause}" if defined $req->{heldBecause};
}
if (defined $req->{notes}) {
print "...\n Notes: $req->{notes}";
}
print "\n\n";
}
}
print "END: $id, ", $sp->getLedgerEntityId($id);
@ -108,6 +110,6 @@ print "No entries found\n" unless $found;
###############################################################################
#
# Local variables:
# compile-command: "perl -c send-mass-email.plx"
# compile-command: "perl -I../Supporters/lib -c find-supporter.plx"
# End:

View file

@ -7,6 +7,7 @@ use warnings;
use autodie qw(open close chdir);
use DBI;
use Encode qw(encode decode);
use Text::CSV; # libtext-csv-perl in Debian
use YAML::XS qw(LoadFile);
@ -20,15 +21,27 @@ require 'bean-query-daemon-lib.pl';
binmode STDOUT, ":utf8";
BeancountQueryInitialize();
if (@ARGV < 9) {
print STDERR "usage: $0 <SUPPORTERS_SQLITE_DB_FILE> <GIVING_LIMIT> <T-SHIRT-STYLE> <SIZE_COUNTS> <OUTPUT_DIRECTORY > <MONTHLY_SEARCH_REGEX> <ANNUAL_SEARCH_REGEX> <VERBOSE> <LEDGER_CMD_LINE>\n";
if (@ARGV < 8 or @ARGV > 9) {
print STDERR "usage: $0 <SUPPORTERS_SQLITE_DB_FILE> <GIVING_LIMIT> <T-SHIRT-STYLE> <SIZE_COUNTS> <ID_IN_USA_FILE> <MONTHLY_SEARCH_REGEX> <ANNUAL_SEARCH_REGEX> <VERBOSE>\n";
exit 1;
}
my($SUPPORTERS_SQLITE_DB_FILE, $GIVING_LIMIT, $T_SHIRT_STYLE, $SIZE_COUNT_FILE, $OUTPUT_DIRECTORY, $MONTHLY_SEARCH_REGEX, $ANNUAL_SEARCH_REGEX, $VERBOSE, @LEDGER_CMD_LINE) = @ARGV;
my($SUPPORTERS_SQLITE_DB_FILE, $GIVING_LIMIT, $T_SHIRT_STYLE, $SIZE_COUNT_FILE, $ID_IN_USA_FILE, $MONTHLY_SEARCH_REGEX, $ANNUAL_SEARCH_REGEX, $VERBOSE) = @ARGV;
$VERBOSE = 0 if not defined $VERBOSE;
my($sizeCounts) = LoadFile $SIZE_COUNT_FILE;
open(my $idsInUSAFH, "<", $ID_IN_USA_FILE);
my %idsKnownToBeInUSA;
while (my $idInUSA = <$idsInUSAFH>) {
chomp $idInUSA;
$idsKnownToBeInUSA{$idInUSA} = 1;
}
my(@usaRows, @intRows);
my($sizeCounts);
$sizeCounts = LoadFile $SIZE_COUNT_FILE if (defined $SIZE_COUNT_FILE and -r $SIZE_COUNT_FILE);
my $dbh = DBI->connect("dbi:SQLite:dbname=$SUPPORTERS_SQLITE_DB_FILE", "", "",
{ RaiseError => 1, sqlite_unicode => 1 })
@ -50,7 +63,12 @@ my %lines;
my @typeList;
my @oldTypeList;
if ($T_SHIRT_STYLE eq 'fy2018design') {
if ($T_SHIRT_STYLE eq 'ONLY-fy2021design') {
@typeList = qw/t-shirt-fy2021design-0/;
} elsif ($T_SHIRT_STYLE eq 'fy2021design') {
@typeList = qw/t-shirt-fy2021design-0 t-shirt-fy2018design-0 t-shirt-vintage-0/;
@oldTypeList = qw/t-shirt-0 t-shirt-1 t-shirt-extra-0 t-shirt-extra-1/;
} elsif ($T_SHIRT_STYLE eq 'fy2018design') {
@typeList = qw/t-shirt-fy2018design-0 t-shirt-vintage-0/;
@oldTypeList = qw/t-shirt-0 t-shirt-1 t-shirt-extra-0 t-shirt-extra-1/;
} elsif ($T_SHIRT_STYLE == 0) {
@ -77,10 +95,6 @@ foreach my $id (@supporterIds) {
$requestData{$id}{lastGaveDate} = $lastGaveDate unless defined $requestData{$id}{lastGaveDate};
$requestData{$id}{oldestShirtDate} = '9999-12-31' unless defined $requestData{$id}{oldestShirtDate};
$requestData{$id}{forSortingbySize} = "" unless defined $requestData{$id}{forSortingbySize};
$requestData{$id}{forSorting_trueVintageCount} = 0 unless defined $requestData{$id}{forSorting_trueVintageCount};
$requestData{$id}{forSorting_trueVintageCount}++ if ($type =~ /vint/i);
print STDERR "$id: $type, need vint $requestData{$id}{forSorting_trueVintageCount}\n" if ($type =~ /vint/i);
$requestData{$id}{shirts}{$request->{requestType}} = $request;
$requestData{$id}{forSortingbySize} = $request->{requestConfiguration}
@ -90,83 +104,126 @@ foreach my $id (@supporterIds) {
}
}
}
sub sortFunction($$) { ($requestData{$_[1]}{forSorting_trueVintageCount} <=> $requestData{$_[0]}{forSorting_trueVintageCount}) or
(($requestData{$_[0]}{lastGaveDate} ge '2020-11-01')
<=> ($requestData{$_[1]}{lastGaveDate} ge '2020-11-01')) or
return ( ($requestData{$_[0]}{oldestShirtDate} cmp $requestData{$_[1]}{oldestShirtDate} or
$requestData{$_[0]}{lastGaveDate} cmp $requestData{$_[1]}{lastGaveDate}) or
sub sortFunction($$) { return (($requestData{$_[1]}{total} <=> $requestData{$_[0]}{total}) or
($requestData{$_[1]}{lastGaveDate} cmp $requestData{$_[0]}{lastGaveDate}) or
($requestData{$_[0]}{oldestShirtDate} cmp $requestData{$_[1]}{oldestShirtDate}) or
($requestData{$_[0]}{forSortingbySize} cmp $requestData{$_[1]}{forSortingbySize}) or
($_[0] <=> $_[1]));
}
my %need;
foreach my $id (sort { sortFunction($a, $b); } keys %requestData) {
my %emails;
my $email = $sp->getPreferredEmailAddress($id);
if (defined $email) {
$emails{$email} = {};
} else {
%emails = $sp->getEmailAddresses($id);
}
my(@emails) = keys(%emails);
next if $id == 20 or $id == 70 or $id == 670 or $id == 34;
next if $id == 20; # Skip bkuhn, he can wait forever for shirts if needed.
my $bestPostal = $sp->getBestPostalAddress($id);
unless (defined $bestPostal) {
warn "Supporter $id: unable to find best postal address!";
next;
my $email = $sp->getPreferredEmailAddress($id);
my @emails;
if (not defined $email) {
my(%emails) = $sp->getEmailAddresses($id);
my $bestDate = '0001-01-01';
foreach my $possibleEmail (keys %emails) {
push(@emails, $possibleEmail);
print STDERR "$emails{$email}{date_encountered} gt $bestDate\n";
if ($emails{$possibleEmail}{date_encountered} gt $bestDate) {
$email = $possibleEmail; $bestDate = $emails{$possibleEmail}{date_encountered};
}
my $hasOrGets2018 = 0;
my $request = $sp->getRequest({ donorId => $id, requestType => 't-shirt-fy2018design-0', ignoreHeldRequests => 1});
$hasOrGets2018 = 1 if (defined $request);
}
} else {
@emails = qw/$email/;
}
print STDERR "Supporter $id has no email address\n" if not defined $email;
my($specificRequest2018, $specificRequest2021) = (0, 0);
my $request = $sp->getRequest({ donorId => $id, requestType => 't-shirt-fy2018design-0' });
$specificRequest2018 = (defined $request);
$request = $sp->getRequest({ donorId => $id, requestType => 't-shirt-fy2021design-0' });
$specificRequest2021 = (defined $request);
my $bestPostal;
my $remainingQualifyingDonations = $requestData{$id}{total};
next if $remainingQualifyingDonations < 60.00; # Must have given at least $60 to get a shirt.
my $outputSoFar = "$id:\n" . " oldest request: $requestData{$id}{oldestShirtDate}\n" .
" lastGave: $requestData{$id}{lastGaveDate}\n" .
" total: " . sprintf('%8.2f', $requestData{$id}{total}) ."\n" .
" emails: " . join(", ", @emails) . "\n" .
" email_for_ship: " . $email . "\n" .
" shirts: $id,";
my @shirtTypes;
my $requestDates = "";
my($finalOutputType, $finalSize);
foreach my $type (sort { $requestData{$id}{shirts}{$a}{requestDate} cmp $requestData{$id}{shirts}{$b}{requestDate} } keys %{$requestData{$id}{shirts}}) {
my $outputType = $type;
my $size = $requestData{$id}{shirts}{$type}{requestConfiguration};
die "$id $type request has no size!" unless defined $size;
last if $remainingQualifyingDonations < 60.00;
if ($hasOrGets2018) {
if ($type =~ /2018/) {
$outputType = "2018design";
} elsif ($type =~ /vint/i) {
$outputType = "vintage";
} else {
$outputType = "any";
}
} elsif ($type !~ /vint/i) {
$outputType = "2018design";
$hasOrGets2018 = 1;
$remainingQualifyingDonations -= 60.00;
if ($type !~ /(2018|2021|vintage)/) {
$outputType = 'any';
} elsif ($type =~ /2018/) {
$outputType = '2018design';
} elsif ($type =~ /2021/) {
$outputType = '2021design';
} elsif ($type =~ /vintage/) {
$outputType = 'vintage';
}
#if ($wantedOrGotBoth2018And2021) {
# if ($type =~ /2018/) {
# if ($type =~ /2018/) {
# $outputType = "2018design";
# } elsif ($type =~ /2021/) {
# $outputType = "2021design";
# } elsif ($type =~ /vint/i) {
# $outputType = "vintage";
# } else {
# $outputType = "any";
# }
# } elsif ($type !~ /vint/i) {
# $outputType = "2021design";
# } else {
# $outputType = "vintage";
# }
$size = "Standard$size" if $size =~ /^Ladies/;
# The commented out code below is designed to handle the sizeCounts and make best guess about what
# shirt to send.
die "Supporter $id: $outputType: $type: $size: invalid size \"$size\""
unless ($outputType ne 'any' and defined $sizeCounts->{$outputType}{$size})
or ($outputType eq 'any' and defined $sizeCounts->{vintage}{$size});
if ($outputType eq 'any' and $sizeCounts->{vintage}{$size} > 0) {
if ($outputType eq 'vintage' and $sizeCounts->{vintage}{$size} <= 0
and defined $sizeCounts->{'vintage-green'} and $sizeCounts->{'vintage-green'}{$size} > 0) {
$outputType = 'vintage-green';
} elsif ($outputType eq 'any' and $specificRequest2021 and $specificRequest2018) {
$outputType = 'vintage';
} elsif ($outputType eq 'any' and $sizeCounts->{'vintage-green'}{$size} > 0 and $hasOrGets2018) {
$outputType = 'vintage';
} elsif ($outputType eq 'any') {
} elsif ($outputType eq 'any' and $specificRequest2018) {
$outputType = '2021design';
} elsif ($outputType eq 'any' and $specificRequest2021) {
$outputType = '2018design';
} elsif ($outputType eq 'any') {
foreach my $reType (qw/2021design 2018design vintage-green vintage/) {
if ($sizeCounts->{$reType}{$size} > 0) {
print "$id: bkuhn Using $outputType request as $reType\n";
$outputType = $reType;
last;
}
die "Supporter $id: $outputType: $type: $size: How are we still any?" if $outputType eq 'any';
if ($sizeCounts->{$outputType}{$size} < 0) {
}
}
if ($outputType ne 'any' and $sizeCounts->{$outputType}{$size} < 0) {
die "Somehow size count for $outputType, $size got to be less than zero!!!";
} elsif ($sizeCounts->{$outputType}{$size} == 0) {
} elsif ($outputType eq 'any' or $sizeCounts->{$outputType}{$size} == 0) {
$need{$outputType}{$size} = 0 unless defined $need{$outputType}{$size};
$need{$outputType}{$size}++;
if ($outputType eq 'vintage') {
warn "Supporter $id: $type: $size: needs a vintage shirt *specifically* which we do not have";
}
$remainingQualifyingDonations -= 60.00;
next;
}
# Continue on only if we have sizes left
$bestPostal = $sp->getBestPostalAddress($id);
unless (defined $bestPostal) {
warn "Supporter $id: unable to find best postal address!";
next;
}
my $likelyUSA = 1
if ($idsKnownToBeInUSA{$id} or ($bestPostal =~ /United\s*States|USA|,\s*\S+\s+\d{5,5}(\s+|$)|,\s*\S+\s+\d{5,5}\-\d{4,4}(\s+|$)/mi
and (not $bestPostal =~ /Saudi\s*Arabia|France|Sweden|Uruguay|Bulgaria|Indonesia|Switzerland|Spain|Brasil|Brazil|Estonia|Germany|Bosnia|Herzegovina|Italy|Czech|Finland|Korea|Ireland|Israel/im)));
if (not $likelyUSA and $bestPostal =~ /Russia/im) {
warn "Support $id: CANNOT CURRENTLY SHIP TO RUSSIA";
next;
}
# # Continue on only if we have sizes left
$sizeCounts->{$outputType}{$size}--;
$totalSent++;
if ($requestDates ne "") {
@ -174,11 +231,33 @@ foreach my $id (sort { sortFunction($a, $b); } keys %requestData) {
$outputSoFar .= ",";
}
$outputSoFar .= "${size}_$outputType";
push(@shirtTypes, $type);
$requestDates .= $requestData{$id}{shirts}{$type}{requestDate};
# Order ID (required),Order Date,Order Value,Requested Service,Ship To - Name,Ship To - Company,Ship To - Address 1,Ship To - Address 2,Ship To - Address 3,Ship To - State/Province,Ship To - City,Ship To - Postal Code,Ship To - Country,Ship To - Phone,Ship To - Email,Total Weight in Oz,Dimensions - Length,Dimensions - Width,Dimensions - Height,Notes - From Customer,Notes - Internal,Gift Wrap?,Gift Message
my $orderID = $outputType . '_' . $size . '_' . $requestData{$id}{shirts}{$type}{requestDate} . '_' . sprintf("%4.4d", $id);
$orderID =~ s/\s*//;
my $outputAddress = join(" ", split /\n/, $bestPostal);
$outputAddress = $bestPostal;
if ($likelyUSA) {
push(@usaRows, [ $orderID, $requestData{$id}{shirts}{$type}{requestDate},
sprintf('%s_%s_%4.4d', $size, $outputType, $id), $size, $email,
"USA", $outputAddress ] );
} else {
push(@intRows, [ $orderID, $requestData{$id}{shirts}{$type}{requestDate},
sprintf('%s_%s_%4.4d', $size, $outputType, $id), $size, $email,
"International", $outputAddress ] );
}
}
next if $requestDates eq "";
my $shirtTypes;
foreach my $type (sort { $a cmp $b } @shirtTypes) {
$shirtTypes .= "," if defined $shirtTypes;
$shirtTypes = " SHIRT_TYPES: " if not defined $shirtTypes;
$shirtTypes .= $type;
}
print "#" x 75;
print "\n$outputSoFar";
print "\n$outputSoFar\n$shirtTypes\n";
print "\n Request Dates: $requestDates\n";
print " LedgerEntityId: ", $sp->getLedgerEntityId($id), "\n";
print " Display name: \"", $sp->getDisplayName($id), "\"\n";
@ -187,22 +266,47 @@ foreach my $id (sort { sortFunction($a, $b); } keys %requestData) {
BeancountQueryComplete();
my $totalNeed = 0;
print "FINAL INVENTORY\n";
foreach my $type (sort { $a cmp $b } keys %$sizeCounts) {
my %subtotals;
if (defined $sizeCounts) {
print "FINAL INVENTORY\n";
foreach my $type (sort { $a cmp $b } keys %$sizeCounts) {
print "$type:\n";
foreach my $size (sort { $a cmp $b } keys %{$sizeCounts->{$type}}) {
print " $size: $sizeCounts->{$type}{$size}\n";
}
}
print "NEED INVENTORY\n";
foreach my $type (sort { $a cmp $b } keys %need) {
}
print "NEED INVENTORY\n";
foreach my $type (sort { $a cmp $b } keys %need) {
print "$type:\n";
$subtotals{$type} = 0;
foreach my $size (sort { $a cmp $b } keys %{$need{$type}}) {
print " $size: $need{$type}{$size}\n";
$totalNeed += $need{$type}{$size};
$subtotals{$type} += $need{$type}{$size}
}
}
}
print "TOTAL SENT: $totalSent ; TOTAL NEED: $totalNeed\n";
print "TOTAL SENT: $totalSent ";
if (defined $sizeCounts) {
print "\n\nTOTAL NEED: $totalNeed\n";
foreach my $type (sort { $a cmp $b } keys %need) {
print " ... includes subtotal of $type: $subtotals{$type}\n";
}
}
open my $usaFH, ">:encoding(utf8)", "usa.csv";
open my $intFH, ">:encoding(utf8)", "international.csv";
my $usaCSV = Text::CSV->new({ binary => 1, quote_char => '"', allow_whitespace => 1, always_quote => 1,
sep_char => ',', escape_char => "\\", auto_diag => 2, diag_verbose => 2 });
my $intCSV = Text::CSV->new({ binary => 1, quote_char => '"', allow_whitespace => 1, always_quote => 1,
sep_char => ',', escape_char => "\\", auto_diag => 2, diag_verbose => 2 });
my @headers = qw/orderId orderDate myReference size email usaOrInt formattedAddress/;
$usaCSV->say($usaFH, \@headers);
$intCSV->say($intFH, \@headers);
$usaCSV->say($usaFH, $_) for @usaRows; close $usaFH;
$intCSV->say($intFH, $_) for @intRows; close $intFH;
###############################################################################
#
# Local variables:

View file

@ -109,9 +109,9 @@ CREATE TABLE "address_type" (
"name" varchar(50) NOT NULL UNIQUE
);
DROP TABLE IF EXISTS "postal_address";
DROP TABLE IF EXISTS "old_postal_address";
CREATE TABLE "postal_address" (
CREATE TABLE "old_postal_address" (
"id" integer NOT NULL PRIMARY KEY,
"formatted_address" varchar(5000),
"type_id" INTEGER NOT NULL,
@ -119,17 +119,48 @@ CREATE TABLE "postal_address" (
"invalid" bool
);
DROP TABLE IF EXISTS "old_donor_postal_address_mapping";
CREATE TABLE "old_donor_postal_address_mapping" (
"donor_id" integer NOT NULL,
"old_postal_address_id" integer NOT NULL,
"preferred" bool,
PRIMARY KEY(donor_id, postal_address_id)
);
CREATE UNIQUE INDEX old_donor_postal_address_mapping_single_prefferred_per_donor
ON old_donor_postal_address_mapping(donor_id, preferred);
DROP TABLE IF EXISTS "postal_address";
CREATE TABLE "postal_address" (
"id" integer NOT NULL PRIMARY KEY,
"first_name" varchar(64),
"middle_name" varchar(64),
"last_name" varchar(64),
"organization" varchar(64),
"address_1" varchar(128),
"address_2" varchar(128),
"address_3" varchar(128),
"city" varchar(64),
"state_province_or_region" varchar(64),
"postcode" varchar(64),
"country" varchar(64)
);
DROP TABLE IF EXISTS "donor_postal_address_mapping";
CREATE TABLE "donor_postal_address_mapping" (
"donor_id" integer NOT NULL,
"postal_address_id" integer NOT NULL,
"preferred" bool,
"type_id" INTEGER NOT NULL,
"date_valid_from" date NOT NULL,
"date_valid_to" date,
PRIMARY KEY(donor_id, postal_address_id)
);
CREATE UNIQUE INDEX donor_postal_address_mapping_single_prefferred_per_donor
ON donor_postal_address_mapping(donor_id, preferred);
CREATE UNIQUE INDEX donor_postal_address_mapping_single_open_ended_addr
ON donor_postal_address_mapping(donor_id, date_valid_to);
-- ####################################### VIEWS FOR EASIER EDITING ##########################
@ -140,87 +171,110 @@ CREATE UNIQUE INDEX donor_postal_address_mapping_single_prefferred_per_donor
-- Note: CREATE TEMP TABLE doesn't work in BEGIN/END block of a CREATE TRIGGER, and as such, we have to create
-- all the temp tables as real tables.
-- -------------- VIEW: UserOperation_update_postal_address ---------------------
-- -------------- VIEW: UserOperation_update_email_address ---------------------
DROP VIEW IF EXISTS UserOperation_email_add_when_none;
CREATE VIEW UserOperation_email_add_when_none AS
SELECT ledger_entity_id as entity, map.preferred as preferred_override, ea.date_encountered as entered_date,
ea.email_address as email_address, ea.id as address_id, dd.id as donor_id
FROM donor dd
LEFT JOIN donor_email_address_mapping map ON dd.id = map.donor_id
LEFT JOIN email_address ea ON ea.id = map.email_address_id
WHERE map.donor_id is NULL
ORDER BY ledger_entity_id;
DROP VIEW IF EXISTS UserOperation_postal_address_change;
CREATE VIEW UserOperation_postal_address_change AS
SELECT ledger_entity_id as donor_name, map.preferred as preferred_override, pa.date_encountered as entered_date,
pa.formatted_address as formatted_postal_address, pa.id as address_id, dd.id as donor_id, pa.invalid as is_invalid
FROM donor dd, donor_postal_address_mapping map, postal_address pa
WHERE dd.id = map.donor_id AND pa.id = map.postal_address_id
AND map.preferred is NOT NULL
UNION
SELECT ledger_entity_id as donor_name, map.preferred as preferred_override, pa.date_encountered as entered_date,
pa.formatted_address as formatted_postal_address, pa.id as address_id, dd.id as donor_id, pa.invalid as is_invalid
FROM donor dd, donor_postal_address_mapping map, postal_address pa
WHERE dd.id = map.donor_id AND pa.id = map.postal_address_id
AND map.preferred is NULL
AND pa.date_encountered = (SELECT max(sub_pa.date_encountered)
FROM donor_postal_address_mapping sub_map, postal_address sub_pa
WHERE sub_map.donor_id = dd.id AND sub_map.postal_address_id = sub_pa.id)
ORDER BY ledger_entity_id, pa.date_encountered;
DROP TRIGGER IF EXISTS update_postal_address_preferred_override;
CREATE TRIGGER update_postal_address_preferred_override
INSTEAD OF UPDATE OF preferred_override on UserOperation_postal_address_change
DROP TRIGGER IF EXISTS add_email_address;
CREATE TRIGGER add_email_address
INSTEAD OF UPDATE OF email_address on UserOperation_email_add_when_none
BEGIN
UPDATE donor_postal_address_mapping SET preferred = NEW.preferred_override
WHERE donor_id = OLD.donor_id and postal_address_id = OLD.address_id;
INSERT INTO email_address(email_address, type_id, date_encountered)
VALUES(NEW.email_address, 21, date("now"));
SELECT CASE
WHEN ( (SELECT preferred FROM donor_postal_address_mapping
WHERE donor_id = OLD.donor_id AND postal_address_Id = OLD.address_id)
!= NEW.preferred_override )
THEN RAISE(FAIL, "Error encountered while updating preferred setting; please verify your changes worked!")
END;
END;
DROP TRIGGER IF EXISTS update_postal_address_is_invalid;
CREATE TRIGGER update_postal_address_is_invalid
INSTEAD OF UPDATE OF is_invalid on UserOperation_postal_address_change
BEGIN
UPDATE postal_address SET invalid = NEW.is_invalid
WHERE id = OLD.address_id;
SELECT CASE
WHEN ( (SELECT invalid FROM postal_address
WHERE id = OLD.address_id)
!= NEW.is_invalid )
THEN RAISE(FAIL, "Error encountered while updating invalid setting; please verify your changes worked!")
END;
END;
DROP TRIGGER IF EXISTS update_formatted_postal_address;
CREATE TRIGGER update_formatted_postal_address
INSTEAD OF UPDATE OF formatted_postal_address on UserOperation_postal_address_change
BEGIN
INSERT INTO postal_address(formatted_address, type_id, date_encountered)
VALUES(NEW.formatted_postal_address, 21, date("now"));
-- WITH wt(new_postal_address_id) AS (SELECT last_insert_rowid() AS new_postal_address_id)
INSERT INTO donor_postal_address_mapping(donor_id, postal_address_id)
INSERT INTO donor_email_address_mapping(donor_id, email_address_id)
VALUES(OLD.donor_id, (SELECT last_insert_rowid() ));
-- VALUES(OLD.donor_id, (SELECT new_postal_address_id FROM wt) );
SELECT CASE
WHEN ( (SELECT formatted_address FROM donor_postal_address_mapping dp, postal_address pa
WHERE dp.donor_id = OLD.donor_id
AND pa.id = (SELECT last_insert_rowid() )
AND dp.postal_address_id = (SELECT last_insert_rowid() )
AND pa.formatted_address = NEW.formatted_postal_address
!= NEW.formatted_postal_address ) )
WHEN ( (SELECT email_address FROM donor_email_address_mapping de, email_address ea
WHERE de.donor_id = OLD.donor_id
AND ea.id = (SELECT last_insert_rowid() )
AND de.email_address_id = (SELECT last_insert_rowid() )
AND ea.email_address = NEW.email_address
!= NEW.email_address ) )
THEN RAISE(FAIL, "Error encountered while adding new postal address; please verify your changes worked!")
END;
END;
-- -------------- VIEW: UserOperation_update_postal_address ---------------------
DROP TRIGGER IF EXISTS update_postal_address_preferred_override;
DROP TRIGGER IF EXISTS update_postal_address_is_invalid;
DROP TRIGGER IF EXISTS update_formatted_postal_address;
DROP VIEW IF EXISTS UserOperation_postal_address_change;
CREATE VIEW UserOperation_postal_address_change AS
SELECT dd.id as donor_id, ledger_entity_id as entity, map.date_valid_from as entered_date, map.date_valid_to as invalidated_date,
pa.first_name as first_n, pa.middle_name as middle_n, pa.last_name as last_n, pa.organization as org,
pa.address_1 as addr1, pa.address_2 as addr2, pa.address_3 as addr3, pa.city as city,
pa.state_province_or_region as state_or_region, pa.postcode as postcode, pa.country as country, pa.id AS postal_id
FROM donor dd
LEFT JOIN donor_postal_address_mapping map ON dd.id = map.donor_id
LEFT JOIN postal_address pa ON pa.id = map.postal_address_id
WHERE dd.is_supporter = 1
AND (map.date_valid_to is NULL OR map.date_valid_to = (SELECT max(date_valid_to) FROM donor_postal_address_mapping where donor_id = dd.id
AND donor_id NOT IN (SELECT donor_id FROM donor_postal_address_mapping WHERE date_valid_to IS NULL)))
ORDER BY ledger_entity_id;
DROP TRIGGER IF EXISTS update_postal_address_from_add_UserOperation;
CREATE TRIGGER update_postal_address_from_add_UserOperation
INSTEAD OF INSERT ON UserOperation_postal_address_change
BEGIN
UPDATE donor_postal_address_mapping SET date_valid_to = date("now")
WHERE donor_id = NEW.donor_id AND date_valid_to IS NULL;
INSERT INTO postal_address(first_name, middle_name, last_name, organization, address_1, address_2,
address_3, city, state_province_or_region, postcode, country)
VALUES(NEW.first_n, NEW.middle_n, NEW.last_n, NEW.org, NEW.addr1, NEW.addr2,
NEW.addr3, NEW.city, NEW.state_or_region, NEW.postcode, NEW.country);
-- WITH wt(new_postal_address_id) AS (SELECT last_insert_rowid() AS new_postal_address_id)
INSERT INTO donor_postal_address_mapping(donor_id, postal_address_id, type_id, date_valid_from)
VALUES(NEW.donor_id, (SELECT last_insert_rowid()), 21, date("now"));
-- VALUES(OLD.donor_id, (SELECT new_postal_address_id FROM wt) );
SELECT CASE
WHEN ( (SELECT address_1 FROM donor_postal_address_mapping dp, postal_address pa
WHERE dp.donor_id = NEW.donor_id
AND pa.id = (SELECT last_insert_rowid() )
AND dp.postal_address_id = (SELECT last_insert_rowid() )
AND pa.address_1 = NEW.addr1
!= NEW.addr1 ) )
THEN RAISE(FAIL, "Error encountered while adding new postal address; please verify your changes worked!")
END;
END;
DROP TRIGGER IF EXISTS invalidate_postal_address_from_UserOperation;
CREATE TRIGGER invalidate_postal_address_from_UserOperation
INSTEAD OF UPDATE OF invalidated_date
ON UserOperation_postal_address_change
BEGIN
SELECT CASE
WHEN ( OLD.postal_id is NULL )
THEN RAISE(FAIL, "Donor has no postal address yet; cannot invalidate non existent address.")
END;
UPDATE donor_postal_address_mapping SET date_valid_to = NEW.invalidated_date WHERE donor_id = OLD.donor_id AND postal_address_id = OLD.postal_id;
-- FIXME, WHY DOES THE BELOW NOT WORK IN sqlitebrowser
-- SELECT CASE
-- WHEN ( (SELECT date_valid_to FROM donor_postal_address_mapping
-- WHERE donor_id = OLD.donor_id
-- AND postal_address_id = OLD.postal_id
-- != NEW.invalidated_date ) )
-- THEN RAISE(FAIL, "Error encountered while invalidating postal address; please verify your changes worked!")
-- END;
END;
-- -------------- VIEW: UserOperation_fix_tshirt_size_request ---------------------
DROP TABLE IF EXISTS "zz__temp_request_configuration_change";
@ -232,7 +286,7 @@ CREATE TABLE zz__temp_request_configuration_change(
DROP VIEW IF EXISTS UserOperation_fix_tshirt_size_request;
CREATE VIEW UserOperation_fix_tshirt_size_request AS
SELECT donor.ledger_entity_id as donor_name,
SELECT donor.ledger_entity_id as entity,
request_type.type as shirt_requested, request_configuration.description as size_requested,
request.date_requested as request_date, request.notes as note, donor.id as donor_id, request.id as request_id
FROM donor, request_configuration, request, request_type
@ -289,11 +343,19 @@ END;
DROP VIEW IF EXISTS UserOperation_donor_update;
CREATE VIEW UserOperation_donor_update AS
SELECT donor.ledger_entity_id as donor_name, donor.rt_ticket as ticket, donor.display_name as public_name,
SELECT donor.ledger_entity_id as entity, donor.rt_ticket as ticket, donor.display_name as public_name,
donor.public_ack as public_acknowledge, donor.is_supporter as is_sustainer, donor.id as donor_id
FROM donor
ORDER BY donor.ledger_entity_id, donor.id;
DROP TRIGGER IF EXISTS donor_update_insert_new_donor;
CREATE TRIGGER donor_update_insert_new_donor
INSTEAD OF INSERT ON UserOperation_donor_update
BEGIN
INSERT INTO donor(ledger_entity_id, display_name, public_ack, rt_ticket, is_supporter)
VALUES(NEW.entity, NEW.public_name, NEW.public_acknowledge, NEW.ticket, 1);
END;
DROP TRIGGER IF EXISTS donor_update_display_name;
CREATE TRIGGER donor_update_display_name
INSTEAD OF UPDATE OF public_name on UserOperation_donor_update
@ -370,7 +432,7 @@ CREATE VIEW UserQuery_contact_settings AS
DROP VIEW IF EXISTS UserOperation_contact_setting_change;
CREATE VIEW UserOperation_contact_setting_change AS
SELECT dd.ledger_entity_id as donor_name, rt.type as contact_setting, rc.description as setting_requested,
SELECT dd.ledger_entity_id as entity, rt.type as contact_setting, rc.description as setting_requested,
rr.date_requested as request_date, rr.notes as note, dd.id as donor_id, rr.id as request_id
FROM donor dd
LEFT JOIN request rr ON dd.id = rr.donor_id AND rr.request_type_id = 12
@ -378,6 +440,23 @@ CREATE VIEW UserOperation_contact_setting_change AS
LEFT JOIN request_type rt ON rt.id = rr.request_type_id
ORDER BY dd.ledger_entity_id, rr.date_requested;
DROP TRIGGER IF EXISTS contact_setting_note_updater;
CREATE TRIGGER contact_setting_note_updater
INSTEAD OF UPDATE OF note on UserOperation_contact_setting_change
BEGIN
SELECT CASE
WHEN ( OLD.setting_requested IS NULL )
THEN RAISE(FAIL, "Invalid note setting; Cannot write note on when setting_requested is NULL")
END;
UPDATE request
SET notes = NEW.note
WHERE id = OLD.request_id
AND OLD.request_id is NOT NULL
AND OLD.donor_id = donor_id
AND request_type_id = 12;
END;
DROP TRIGGER IF EXISTS contact_setting_config_change_updater;
CREATE TRIGGER contact_setting_config_change_updater
INSTEAD OF UPDATE OF setting_requested on UserOperation_contact_setting_change
@ -410,7 +489,7 @@ SELECT CASE
END;
INSERT OR IGNORE INTO request(donor_id, request_type_id, request_configuration_id, date_requested, notes)
VALUES(NEW.donor_id, 12,
VALUES(OLD.donor_id, 12,
(SELECT new_request_configuration_id from zz__temp_request_configuration_change),
date("now"), NEW.note);