Use WC lookup tables for improved performance
This commit is part of a task to allow multiple values in "is in country" segment. This commit replaces the queries with the more performant ones written by @lysyjan. It also creates the lookup tables on the integration database and updates the test. [MAILPOET-3952]
This commit is contained in:
@@ -5,6 +5,7 @@ namespace MailPoet\Segments\DynamicSegments\Filters;
|
|||||||
use MailPoet\Entities\DynamicSegmentFilterData;
|
use MailPoet\Entities\DynamicSegmentFilterData;
|
||||||
use MailPoet\Entities\DynamicSegmentFilterEntity;
|
use MailPoet\Entities\DynamicSegmentFilterEntity;
|
||||||
use MailPoet\Entities\SubscriberEntity;
|
use MailPoet\Entities\SubscriberEntity;
|
||||||
|
use MailPoet\Util\DBCollationChecker;
|
||||||
use MailPoet\Util\Security;
|
use MailPoet\Util\Security;
|
||||||
use MailPoetVendor\Doctrine\DBAL\Query\QueryBuilder;
|
use MailPoetVendor\Doctrine\DBAL\Query\QueryBuilder;
|
||||||
use MailPoetVendor\Doctrine\ORM\EntityManager;
|
use MailPoetVendor\Doctrine\ORM\EntityManager;
|
||||||
@@ -15,10 +16,15 @@ class WooCommerceCountry implements Filter {
|
|||||||
/** @var EntityManager */
|
/** @var EntityManager */
|
||||||
private $entityManager;
|
private $entityManager;
|
||||||
|
|
||||||
|
/** @var DBCollationChecker */
|
||||||
|
private $collationChecker;
|
||||||
|
|
||||||
public function __construct(
|
public function __construct(
|
||||||
EntityManager $entityManager
|
EntityManager $entityManager,
|
||||||
|
DBCollationChecker $collationChecker
|
||||||
) {
|
) {
|
||||||
$this->entityManager = $entityManager;
|
$this->entityManager = $entityManager;
|
||||||
|
$this->collationChecker = $collationChecker;
|
||||||
}
|
}
|
||||||
|
|
||||||
public function apply(QueryBuilder $queryBuilder, DynamicSegmentFilterEntity $filter): QueryBuilder {
|
public function apply(QueryBuilder $queryBuilder, DynamicSegmentFilterEntity $filter): QueryBuilder {
|
||||||
@@ -34,21 +40,24 @@ class WooCommerceCountry implements Filter {
|
|||||||
}
|
}
|
||||||
$countryFilterParam = 'countryCode' . $filter->getId() ?? Security::generateRandomString();
|
$countryFilterParam = 'countryCode' . $filter->getId() ?? Security::generateRandomString();
|
||||||
$subscribersTable = $this->entityManager->getClassMetadata(SubscriberEntity::class)->getTableName();
|
$subscribersTable = $this->entityManager->getClassMetadata(SubscriberEntity::class)->getTableName();
|
||||||
|
$collation = $this->collationChecker->getCollateIfNeeded(
|
||||||
|
$subscribersTable,
|
||||||
|
'email',
|
||||||
|
$wpdb->prefix . 'wc_customer_lookup',
|
||||||
|
'email'
|
||||||
|
);
|
||||||
return $queryBuilder->innerJoin(
|
return $queryBuilder->innerJoin(
|
||||||
$subscribersTable,
|
$subscribersTable,
|
||||||
$wpdb->postmeta,
|
$wpdb->prefix . 'wc_customer_lookup',
|
||||||
'postmeta',
|
'customer',
|
||||||
"postmeta.meta_key = '_customer_user' AND $subscribersTable.wp_user_id=postmeta.meta_value"
|
"$subscribersTable.email = customer.email $collation"
|
||||||
)->innerJoin(
|
)->innerJoin(
|
||||||
'postmeta',
|
'customer',
|
||||||
$wpdb->posts,
|
$wpdb->prefix . 'wc_order_stats',
|
||||||
'posts',
|
'orderStats',
|
||||||
"postmeta.post_id = posts.id AND posts.post_status NOT IN ('wc-cancelled', 'wc-failed')"
|
'customer.customer_id = orderStats.customer_id'
|
||||||
)->innerJoin(
|
)->where("customer.country = :$countryFilterParam")
|
||||||
'postmeta',
|
->andWhere('orderStats.status NOT IN ("wc-cancelled", "wc-failed")')
|
||||||
$wpdb->postmeta,
|
->setParameter($countryFilterParam, $countryCode[0]);
|
||||||
'postmetaCountry',
|
|
||||||
"postmeta.post_id = postmetaCountry.post_id AND postmetaCountry.meta_key = '_billing_country' AND postmetaCountry.meta_value = :$countryFilterParam"
|
|
||||||
)->setParameter($countryFilterParam, $countryCode[0]);
|
|
||||||
}
|
}
|
||||||
}
|
}
|
||||||
|
@@ -7,8 +7,7 @@ use MailPoet\Entities\DynamicSegmentFilterEntity;
|
|||||||
use MailPoet\Entities\SegmentEntity;
|
use MailPoet\Entities\SegmentEntity;
|
||||||
use MailPoet\Entities\SubscriberEntity;
|
use MailPoet\Entities\SubscriberEntity;
|
||||||
use MailPoet\Subscribers\SubscribersRepository;
|
use MailPoet\Subscribers\SubscribersRepository;
|
||||||
use MailPoet\WP\Functions as WPFunctions;
|
use MailPoetVendor\Doctrine\DBAL\ForwardCompatibility\DriverStatement;
|
||||||
use MailPoetVendor\Doctrine\DBAL\Driver\Statement;
|
|
||||||
use MailPoetVendor\Doctrine\DBAL\Query\QueryBuilder;
|
use MailPoetVendor\Doctrine\DBAL\Query\QueryBuilder;
|
||||||
|
|
||||||
class WooCommerceCountryTest extends \MailPoetTest {
|
class WooCommerceCountryTest extends \MailPoetTest {
|
||||||
@@ -16,18 +15,12 @@ class WooCommerceCountryTest extends \MailPoetTest {
|
|||||||
/** @var WooCommerceCountry */
|
/** @var WooCommerceCountry */
|
||||||
private $wooCommerceCountry;
|
private $wooCommerceCountry;
|
||||||
|
|
||||||
/** @var WPFunctions */
|
|
||||||
private $wp;
|
|
||||||
|
|
||||||
/** @var int[] */
|
|
||||||
private $orders;
|
|
||||||
|
|
||||||
/** @var SubscribersRepository */
|
/** @var SubscribersRepository */
|
||||||
private $subscribersRepository;
|
private $subscribersRepository;
|
||||||
|
|
||||||
public function _before(): void {
|
public function _before(): void {
|
||||||
|
self::createLookUpTables();
|
||||||
$this->wooCommerceCountry = $this->diContainer->get(WooCommerceCountry::class);
|
$this->wooCommerceCountry = $this->diContainer->get(WooCommerceCountry::class);
|
||||||
$this->wp = $this->diContainer->get(WPFunctions::class);
|
|
||||||
$this->subscribersRepository = $this->diContainer->get(SubscribersRepository::class);
|
$this->subscribersRepository = $this->diContainer->get(SubscribersRepository::class);
|
||||||
|
|
||||||
$this->cleanup();
|
$this->cleanup();
|
||||||
@@ -36,21 +29,22 @@ class WooCommerceCountryTest extends \MailPoetTest {
|
|||||||
$userId2 = $this->tester->createWordPressUser('customer2@example.com', 'customer');
|
$userId2 = $this->tester->createWordPressUser('customer2@example.com', 'customer');
|
||||||
$userId3 = $this->tester->createWordPressUser('customer3@example.com', 'customer');
|
$userId3 = $this->tester->createWordPressUser('customer3@example.com', 'customer');
|
||||||
|
|
||||||
$this->orders[] = $this->createOrder(['user_id' => $userId1, 'billing_country' => 'US']);
|
$this->createCustomerLookupData(['user_id' => $userId1, 'email' => 'customer1@example.com', 'country' => 'CZ']);
|
||||||
$this->orders[] = $this->createOrder(['user_id' => $userId2, 'billing_country' => 'US']);
|
$this->createCustomerLookupData(['user_id' => $userId2, 'email' => 'customer2@example.com', 'country' => 'US']);
|
||||||
$this->orders[] = $this->createOrder(['user_id' => $userId3]);
|
$this->createCustomerLookupData(['user_id' => $userId3, 'email' => 'customer3@example.com', 'country' => 'US']);
|
||||||
}
|
}
|
||||||
|
|
||||||
public function testItAppliesFilter(): void {
|
public function testItAppliesFilter(): void {
|
||||||
$segmentFilter = $this->getSegmentFilter('CZ');
|
$segmentFilter = $this->getSegmentFilter('CZ');
|
||||||
$queryBuilder = $this->wooCommerceCountry->apply($this->getQueryBuilder(), $segmentFilter);
|
$queryBuilder = $this->wooCommerceCountry->apply($this->getQueryBuilder(), $segmentFilter);
|
||||||
$statement = $queryBuilder->execute();
|
$statement = $queryBuilder->execute();
|
||||||
$result = $statement instanceof Statement ? $statement->fetchAll() : [];
|
assert($statement instanceof DriverStatement);
|
||||||
|
$result = $statement->fetchAll();
|
||||||
expect(count($result))->equals(1);
|
expect(count($result))->equals(1);
|
||||||
$subscriber1 = $this->subscribersRepository->findOneById($result[0]['inner_subscriber_id']);
|
$subscriber1 = $this->subscribersRepository->findOneById($result[0]['inner_subscriber_id']);
|
||||||
assert($subscriber1 instanceof SubscriberEntity);
|
assert($subscriber1 instanceof SubscriberEntity);
|
||||||
expect($subscriber1)->isInstanceOf(SubscriberEntity::class);
|
expect($subscriber1)->isInstanceOf(SubscriberEntity::class);
|
||||||
expect($subscriber1->getEmail())->equals('customer3@example.com');
|
expect($subscriber1->getEmail())->equals('customer1@example.com');
|
||||||
}
|
}
|
||||||
|
|
||||||
private function getQueryBuilder(): QueryBuilder {
|
private function getQueryBuilder(): QueryBuilder {
|
||||||
@@ -74,17 +68,40 @@ class WooCommerceCountryTest extends \MailPoetTest {
|
|||||||
return $dynamicSegmentFilter;
|
return $dynamicSegmentFilter;
|
||||||
}
|
}
|
||||||
|
|
||||||
private function createOrder($data): int {
|
private function createCustomerLookupData(array $data) {
|
||||||
return (int)$this->wp->wpInsertPost([
|
$connection = $this->entityManager->getConnection();
|
||||||
'post_type' => 'shop_order',
|
global $wpdb;
|
||||||
'post_status' => 'wc-completed',
|
$customerLookupTable = $wpdb->prefix . 'wc_customer_lookup';
|
||||||
'post_date' => $data['post_date'] ?? '',
|
$connection->executeQuery("
|
||||||
'meta_input' => [
|
INSERT INTO {$customerLookupTable} (user_id, first_name, last_name, email, country)
|
||||||
'_customer_user' => $data['user_id'] ?? '',
|
VALUES (
|
||||||
'_order_total' => $data['order_total'] ?? '1',
|
{$data['user_id']},
|
||||||
'_billing_country' => $data['billing_country'] ?? 'CZ',
|
'',
|
||||||
],
|
'',
|
||||||
]);
|
'{$data['email']}',
|
||||||
|
'{$data['country']}'
|
||||||
|
)
|
||||||
|
");
|
||||||
|
$id = $connection->lastInsertId();
|
||||||
|
$orderId = (int)$id + 1;
|
||||||
|
$orderLookupTable = $wpdb->prefix . 'wc_order_stats';
|
||||||
|
$connection->executeQuery("
|
||||||
|
INSERT INTO {$orderLookupTable} (order_id, status, customer_id)
|
||||||
|
VALUES (
|
||||||
|
{$orderId},
|
||||||
|
'wc-completed',
|
||||||
|
{$id}
|
||||||
|
)
|
||||||
|
");
|
||||||
|
}
|
||||||
|
|
||||||
|
private function cleanUpLookUpTables(): void {
|
||||||
|
$connection = $this->entityManager->getConnection();
|
||||||
|
global $wpdb;
|
||||||
|
$lookupTable = $wpdb->prefix . 'wc_customer_lookup';
|
||||||
|
$orderLookupTable = $wpdb->prefix . 'wc_order_stats';
|
||||||
|
$connection->executeStatement("TRUNCATE $lookupTable");
|
||||||
|
$connection->executeStatement("TRUNCATE $orderLookupTable");
|
||||||
}
|
}
|
||||||
|
|
||||||
public function _after(): void {
|
public function _after(): void {
|
||||||
@@ -99,8 +116,152 @@ class WooCommerceCountryTest extends \MailPoetTest {
|
|||||||
foreach ($emails as $email) {
|
foreach ($emails as $email) {
|
||||||
$this->tester->deleteWordPressUser($email);
|
$this->tester->deleteWordPressUser($email);
|
||||||
}
|
}
|
||||||
foreach ($this->orders ?? [] as $orderId) {
|
$this->cleanUpLookUpTables();
|
||||||
$this->wp->wpDeletePost($orderId);
|
|
||||||
}
|
}
|
||||||
|
|
||||||
|
/**
|
||||||
|
* Get WC Lookup Tables database schema.
|
||||||
|
* Copied from WC-Admin version 2.9.2-plugin
|
||||||
|
*
|
||||||
|
* @return string
|
||||||
|
*/
|
||||||
|
protected static function getSchema(): string {
|
||||||
|
global $wpdb;
|
||||||
|
|
||||||
|
$collate = $wpdb->has_cap( 'collation' ) ? $wpdb->get_charset_collate() : '';
|
||||||
|
|
||||||
|
// Max DB index length. See wp_get_db_schema().
|
||||||
|
$maxIndexLength = 191;
|
||||||
|
|
||||||
|
return "
|
||||||
|
CREATE TABLE {$wpdb->prefix}wc_order_stats (
|
||||||
|
order_id bigint(20) unsigned NOT NULL,
|
||||||
|
parent_id bigint(20) unsigned DEFAULT 0 NOT NULL,
|
||||||
|
date_created datetime DEFAULT '0000-00-00 00:00:00' NOT NULL,
|
||||||
|
date_created_gmt datetime DEFAULT '0000-00-00 00:00:00' NOT NULL,
|
||||||
|
num_items_sold int(11) DEFAULT 0 NOT NULL,
|
||||||
|
total_sales double DEFAULT 0 NOT NULL,
|
||||||
|
tax_total double DEFAULT 0 NOT NULL,
|
||||||
|
shipping_total double DEFAULT 0 NOT NULL,
|
||||||
|
net_total double DEFAULT 0 NOT NULL,
|
||||||
|
returning_customer boolean DEFAULT NULL,
|
||||||
|
status varchar(200) NOT NULL,
|
||||||
|
customer_id BIGINT UNSIGNED NOT NULL,
|
||||||
|
PRIMARY KEY (order_id),
|
||||||
|
KEY date_created (date_created),
|
||||||
|
KEY customer_id (customer_id),
|
||||||
|
KEY status (status({$maxIndexLength}))
|
||||||
|
) $collate;
|
||||||
|
CREATE TABLE {$wpdb->prefix}wc_order_product_lookup (
|
||||||
|
order_item_id BIGINT UNSIGNED NOT NULL,
|
||||||
|
order_id BIGINT UNSIGNED NOT NULL,
|
||||||
|
product_id BIGINT UNSIGNED NOT NULL,
|
||||||
|
variation_id BIGINT UNSIGNED NOT NULL,
|
||||||
|
customer_id BIGINT UNSIGNED NULL,
|
||||||
|
date_created datetime DEFAULT '0000-00-00 00:00:00' NOT NULL,
|
||||||
|
product_qty INT NOT NULL,
|
||||||
|
product_net_revenue double DEFAULT 0 NOT NULL,
|
||||||
|
product_gross_revenue double DEFAULT 0 NOT NULL,
|
||||||
|
coupon_amount double DEFAULT 0 NOT NULL,
|
||||||
|
tax_amount double DEFAULT 0 NOT NULL,
|
||||||
|
shipping_amount double DEFAULT 0 NOT NULL,
|
||||||
|
shipping_tax_amount double DEFAULT 0 NOT NULL,
|
||||||
|
PRIMARY KEY (order_item_id),
|
||||||
|
KEY order_id (order_id),
|
||||||
|
KEY product_id (product_id),
|
||||||
|
KEY customer_id (customer_id),
|
||||||
|
KEY date_created (date_created)
|
||||||
|
) $collate;
|
||||||
|
CREATE TABLE {$wpdb->prefix}wc_order_tax_lookup (
|
||||||
|
order_id BIGINT UNSIGNED NOT NULL,
|
||||||
|
tax_rate_id BIGINT UNSIGNED NOT NULL,
|
||||||
|
date_created datetime DEFAULT '0000-00-00 00:00:00' NOT NULL,
|
||||||
|
shipping_tax double DEFAULT 0 NOT NULL,
|
||||||
|
order_tax double DEFAULT 0 NOT NULL,
|
||||||
|
total_tax double DEFAULT 0 NOT NULL,
|
||||||
|
PRIMARY KEY (order_id, tax_rate_id),
|
||||||
|
KEY tax_rate_id (tax_rate_id),
|
||||||
|
KEY date_created (date_created)
|
||||||
|
) $collate;
|
||||||
|
CREATE TABLE {$wpdb->prefix}wc_order_coupon_lookup (
|
||||||
|
order_id BIGINT UNSIGNED NOT NULL,
|
||||||
|
coupon_id BIGINT NOT NULL,
|
||||||
|
date_created datetime DEFAULT '0000-00-00 00:00:00' NOT NULL,
|
||||||
|
discount_amount double DEFAULT 0 NOT NULL,
|
||||||
|
PRIMARY KEY (order_id, coupon_id),
|
||||||
|
KEY coupon_id (coupon_id),
|
||||||
|
KEY date_created (date_created)
|
||||||
|
) $collate;
|
||||||
|
CREATE TABLE {$wpdb->prefix}wc_admin_notes (
|
||||||
|
note_id BIGINT UNSIGNED NOT NULL AUTO_INCREMENT,
|
||||||
|
name varchar(255) NOT NULL,
|
||||||
|
type varchar(20) NOT NULL,
|
||||||
|
locale varchar(20) NOT NULL,
|
||||||
|
title longtext NOT NULL,
|
||||||
|
content longtext NOT NULL,
|
||||||
|
content_data longtext NULL default null,
|
||||||
|
status varchar(200) NOT NULL,
|
||||||
|
source varchar(200) NOT NULL,
|
||||||
|
date_created datetime NOT NULL default '0000-00-00 00:00:00',
|
||||||
|
date_reminder datetime NULL default null,
|
||||||
|
is_snoozable boolean DEFAULT 0 NOT NULL,
|
||||||
|
layout varchar(20) DEFAULT '' NOT NULL,
|
||||||
|
image varchar(200) NULL DEFAULT NULL,
|
||||||
|
is_deleted boolean DEFAULT 0 NOT NULL,
|
||||||
|
is_read boolean DEFAULT 0 NOT NULL,
|
||||||
|
icon varchar(200) NOT NULL default 'info',
|
||||||
|
PRIMARY KEY (note_id)
|
||||||
|
) $collate;
|
||||||
|
CREATE TABLE {$wpdb->prefix}wc_admin_note_actions (
|
||||||
|
action_id BIGINT UNSIGNED NOT NULL AUTO_INCREMENT,
|
||||||
|
note_id BIGINT UNSIGNED NOT NULL,
|
||||||
|
name varchar(255) NOT NULL,
|
||||||
|
label varchar(255) NOT NULL,
|
||||||
|
query longtext NOT NULL,
|
||||||
|
status varchar(255) NOT NULL,
|
||||||
|
is_primary boolean DEFAULT 0 NOT NULL,
|
||||||
|
actioned_text varchar(255) NOT NULL,
|
||||||
|
nonce_action varchar(255) NULL DEFAULT NULL,
|
||||||
|
nonce_name varchar(255) NULL DEFAULT NULL,
|
||||||
|
PRIMARY KEY (action_id),
|
||||||
|
KEY note_id (note_id)
|
||||||
|
) $collate;
|
||||||
|
CREATE TABLE {$wpdb->prefix}wc_customer_lookup (
|
||||||
|
customer_id BIGINT UNSIGNED NOT NULL AUTO_INCREMENT,
|
||||||
|
user_id BIGINT UNSIGNED DEFAULT NULL,
|
||||||
|
username varchar(60) DEFAULT '' NOT NULL,
|
||||||
|
first_name varchar(255) NOT NULL,
|
||||||
|
last_name varchar(255) NOT NULL,
|
||||||
|
email varchar(100) NULL default NULL,
|
||||||
|
date_last_active timestamp NULL default null,
|
||||||
|
date_registered timestamp NULL default null,
|
||||||
|
country char(2) DEFAULT '' NOT NULL,
|
||||||
|
postcode varchar(20) DEFAULT '' NOT NULL,
|
||||||
|
city varchar(100) DEFAULT '' NOT NULL,
|
||||||
|
state varchar(100) DEFAULT '' NOT NULL,
|
||||||
|
PRIMARY KEY (customer_id),
|
||||||
|
UNIQUE KEY user_id (user_id),
|
||||||
|
KEY email (email)
|
||||||
|
) $collate;
|
||||||
|
CREATE TABLE {$wpdb->prefix}wc_category_lookup (
|
||||||
|
category_tree_id BIGINT UNSIGNED NOT NULL,
|
||||||
|
category_id BIGINT UNSIGNED NOT NULL,
|
||||||
|
PRIMARY KEY (category_tree_id,category_id)
|
||||||
|
) $collate;
|
||||||
|
";
|
||||||
|
}
|
||||||
|
|
||||||
|
/**
|
||||||
|
* Create WC Lookup database tables.
|
||||||
|
*/
|
||||||
|
public static function createLookUpTables() {
|
||||||
|
if ((boolean)getenv('MULTISITE') === true) {
|
||||||
|
$wpUpgradePath = getenv('WP_ROOT_MULTISITE');
|
||||||
|
} else {
|
||||||
|
$wpUpgradePath = getenv('WP_ROOT');
|
||||||
|
}
|
||||||
|
require_once($wpUpgradePath . '/wp-admin/includes/upgrade.php');
|
||||||
|
|
||||||
|
dbDelta( self::getSchema() );
|
||||||
}
|
}
|
||||||
}
|
}
|
||||||
|
Reference in New Issue
Block a user