--upgrade scripts from nopCommerce 3.60 to 3.70 --new locale resources declare @resources xml --a resource will be deleted if its value is empty set @resources=' This product has a minimum quantity of {0} Display tax/shipping info (shopping cart) Check to display tax and shipping info on the shopping cart page. This option is used in Germany. shipping]]> shipping]]> Delete selected Delete selected Delete selected Default language This property allows a store owner to specify a default language for a store. If not specified, then the default language display order will be used. Vendor Search by a specific vendor. Overridden gift card amount Enter gift card amount that can be used after purchase. If not specified, then product price will be used. Customer minimum age Enter minimum allowed age. Leave empty if customers of all ages are allowed. You have to be {0} Hide delivery information Check to hide delivery information as description of returned shipping methods. Rental start date should be the future date Picture The vendor picture. Vendor thumbnail image size The default size (pixels) for vendor thumbnail images. Picture for vendor {0} Show products of vendor {0} Grouped (product with variants) Simple Associated products (variants) Allow customers to apply for vendor account Check to allow customers users to fill a form to become a new vendor. Then a store owner will have to manually approve it. Apply for vendor account Email Enter your email address Email is required. Vendor name Enter vendor name Vendor name is required. Your request has been submitted successfully. We''ll contact you soon. Apply for vendor account Submit You already applied for a vendor account. Please register as a new customer in order to apply for one more vendor account. Points accumulated for all stores Check to accumulate all reward points in one balance for all stores so they can be used in any store. Otherwise, each store has its own rewards points and they can only be used in that store. WARNING: not recommended to change in production environment with several stores already created. Store Store Choose a store. It''s useful only when you have "Points accumulated for all stores" setting disabled. Allow viewing of unpublished product details page Check to allow viewing of unpublished product details page. This way SEO won''t be affected by search crawlers when a product is temporary unpublished. Please note that a store owner always has access to unpublished products. Sorry, you''ve used this discount already Sorry, this discount cannot be used with gift cards in the cart Sorry, this offer is expired Sorry, this offer is not started yet Sorry, this offer requires more money spent (previously placed orders) Some product(s) from wishlist could not be moved to the cart for some reasons. Access control list Subject to ACL Determines whether the topic is subject to ACL (access control list). Customer roles Select customer roles for which the topic will be shown. Back in stock subscriptions Store Product Subscribed on Search Enable to combine (bundle) multiple CSS files into a single file. Do not enable if you''re running nopCommerce in IIS virtual directory. Note that this functionality requires significant server resources (not recommended to use with cheap shared hosting plans). Enable to combine (bundle) multiple JavaScript files into a single file. Note that this functionality requires significant server resources (not recommended to use with cheap shared hosting plans). Condition View/Edit condition Conditional attributes appear if a previous attribute is selected, such as having an option for personalizing clothing with a name and only providing the text input box if the "Personalize" radio button is checked Enable condition Check to specify a condition (depending on other attribute) when this attribute should be enabled (visible). Attribute Choose an attribute. Calculate ''Min order sub-total amount'' including tax Check to calculate ''Min order sub-total amount'' value including tax; otherwise excluding tax. Mark as new Check to mark this product as New Mark as new. Start date Set Product as New from Date in Coordinated Universal Time (UTC). Mark as new. End date Set Product as New to Date in Coordinated Universal Time (UTC). ''New products'' page enabled Check to enable the ''New products'' page in your store Number of products on ''New products'' page The number of products to display when ''New products'' page is enabled. New Products Newsletter Check to subscribe to newsletter. Billing last name Filter by customer billing last name. Billing email address Filter by customer billing email address. Apply to subcategories Check to apply discount to subcategories of the selected parent. But please note that it can affect performance if you have a lot of nested subcategories. Show on apply for vendor account page Check to show CAPTCHA on apply for vendor account page. Return request reasons The new return request reason has been added successfully. Add new return request reason back to return request reason list The return request reason has been deleted successfully. Display order The return request reason display order. 1 represents the first item in the list. Edit return request reason details List of reasons a customer will be able to choose when submitting a return request. Please provide a name. Name The return request reason name. The return request reason has been updated successfully. Return request actions The new return request action has been added successfully. Add new return request action back to return request action list The return request action has been deleted successfully. Display order The return request action display order. 1 represents the first item in the list. Edit return request action details List of actions a customer will be able to choose when submitting a return request. Please provide a name. Name The return request action name. The return request action has been updated successfully. Add new record Store Filter report by orders placed in a specific store. Discontinued message for unpublished products Check to display "a product has been discontinued" message when viewing details pages of unpublished products. Sorry - this product is no longer available Remove Download Reason for return is required Requested action is required Vendor notes Add vendor note Add vendor note Created on Note Enter this vendor note message. Returned back for order #{0} ' CREATE TABLE #LocaleStringResourceTmp ( [ResourceName] [nvarchar](200) NOT NULL, [ResourceValue] [nvarchar](max) NOT NULL ) INSERT INTO #LocaleStringResourceTmp (ResourceName, ResourceValue) SELECT nref.value('@Name', 'nvarchar(200)'), nref.value('Value[1]', 'nvarchar(MAX)') FROM @resources.nodes('//Language/LocaleResource') AS R(nref) --do it for each existing language DECLARE @ExistingLanguageID int DECLARE cur_existinglanguage CURSOR FOR SELECT [ID] FROM [Language] OPEN cur_existinglanguage FETCH NEXT FROM cur_existinglanguage INTO @ExistingLanguageID WHILE @@FETCH_STATUS = 0 BEGIN DECLARE @ResourceName nvarchar(200) DECLARE @ResourceValue nvarchar(MAX) DECLARE cur_localeresource CURSOR FOR SELECT ResourceName, ResourceValue FROM #LocaleStringResourceTmp OPEN cur_localeresource FETCH NEXT FROM cur_localeresource INTO @ResourceName, @ResourceValue WHILE @@FETCH_STATUS = 0 BEGIN IF (EXISTS (SELECT 1 FROM [LocaleStringResource] WHERE LanguageID=@ExistingLanguageID AND ResourceName=@ResourceName)) BEGIN UPDATE [LocaleStringResource] SET [ResourceValue]=@ResourceValue WHERE LanguageID=@ExistingLanguageID AND ResourceName=@ResourceName END ELSE BEGIN INSERT INTO [LocaleStringResource] ( [LanguageId], [ResourceName], [ResourceValue] ) VALUES ( @ExistingLanguageID, @ResourceName, @ResourceValue ) END IF (@ResourceValue is null or @ResourceValue = '') BEGIN DELETE [LocaleStringResource] WHERE LanguageID=@ExistingLanguageID AND ResourceName=@ResourceName END FETCH NEXT FROM cur_localeresource INTO @ResourceName, @ResourceValue END CLOSE cur_localeresource DEALLOCATE cur_localeresource --fetch next language identifier FETCH NEXT FROM cur_existinglanguage INTO @ExistingLanguageID END CLOSE cur_existinglanguage DEALLOCATE cur_existinglanguage DROP TABLE #LocaleStringResourceTmp GO IF NOT EXISTS ( SELECT 1 FROM [MessageTemplate] WHERE [Name] = N'OrderRefunded.CustomerNotification') BEGIN INSERT [MessageTemplate] ([Name], [BccEmailAddresses], [Subject], [Body], [IsActive], [EmailAccountId], [LimitedToStores], [AttachedDownloadId]) VALUES (N'OrderRefunded.CustomerNotification', null, N'%Store.Name%. Order #%Order.OrderNumber% refunded', N'

%Store.Name%

Hello %Order.CustomerFullName%,
Thanks for buying from %Store.Name%. Order #%Order.OrderNumber% has been has been refunded. Please allow 7-14 days for the refund to be reflected in your account.

Amount refunded: %Order.AmountRefunded%

Below is the summary of the order.

Order Number: %Order.OrderNumber%
Order Details: %Order.OrderURLForCustomer%
Date Ordered: %Order.CreatedOn%



Billing Address
%Order.BillingFirstName% %Order.BillingLastName%
%Order.BillingAddress1%
%Order.BillingCity% %Order.BillingZipPostalCode%
%Order.BillingStateProvince% %Order.BillingCountry%



Shipping Address
%Order.ShippingFirstName% %Order.ShippingLastName%
%Order.ShippingAddress1%
%Order.ShippingCity% %Order.ShippingZipPostalCode%
%Order.ShippingStateProvince% %Order.ShippingCountry%

Shipping Method: %Order.ShippingMethod%

%Order.Product(s)%

', 0, 0, 0, 0) END GO --new setting IF NOT EXISTS (SELECT 1 FROM [Setting] WHERE [name] = N'catalogsettings.displaytaxshippinginfoshoppingcart') BEGIN INSERT [Setting] ([Name], [Value], [StoreId]) VALUES (N'catalogsettings.displaytaxshippinginfoshoppingcart', N'false', 0) END GO --new column IF NOT EXISTS (SELECT 1 FROM sys.columns WHERE object_id=object_id('[Store]') and NAME='DefaultLanguageId') BEGIN ALTER TABLE [Store] ADD [DefaultLanguageId] int NULL END GO UPDATE [Store] SET [DefaultLanguageId] = 0 WHERE [DefaultLanguageId] IS NULL GO ALTER TABLE [Store] ALTER COLUMN [DefaultLanguageId] int NOT NULL GO --new column IF NOT EXISTS (SELECT 1 FROM sys.columns WHERE object_id=object_id('[Product]') and NAME='OverriddenGiftCardAmount') BEGIN ALTER TABLE [Product] ADD [OverriddenGiftCardAmount] decimal NULL END GO --new setting IF NOT EXISTS (SELECT 1 FROM [Setting] WHERE [name] = N'customersettings.dateofbirthminimumage') BEGIN INSERT [Setting] ([Name], [Value], [StoreId]) VALUES (N'customersettings.dateofbirthminimumage', N'', 0) END GO --new column IF NOT EXISTS (SELECT 1 FROM sys.columns WHERE object_id=object_id('[Vendor]') and NAME='PictureId') BEGIN ALTER TABLE [Vendor] ADD [PictureId] int NULL END GO UPDATE [Vendor] SET [PictureId] = 0 WHERE [PictureId] IS NULL GO ALTER TABLE [Vendor] ALTER COLUMN [PictureId] int NOT NULL GO --new setting IF NOT EXISTS (SELECT 1 FROM [Setting] WHERE [name] = N'mediasettings.vendorthumbpicturesize') BEGIN INSERT [Setting] ([Name], [Value], [StoreId]) VALUES (N'mediasettings.vendorthumbpicturesize', N'450', 0) END GO --rename some product templates UPDATE [ProductTemplate] SET [Name] = 'Grouped product (with variants)' WHERE [ViewPath] = N'ProductTemplate.Grouped' GO --new setting IF NOT EXISTS (SELECT 1 FROM [Setting] WHERE [name] = N'vendorsettings.allowcustomerstoapplyforvendoraccount') BEGIN INSERT [Setting] ([Name], [Value], [StoreId]) VALUES (N'vendorsettings.allowcustomerstoapplyforvendoraccount', N'false', 0) END GO --new topic IF NOT EXISTS ( SELECT 1 FROM [dbo].[Topic] WHERE [SystemName] = N'ApplyVendor') BEGIN INSERT [dbo].[Topic] ([SystemName], [TopicTemplateId], [IncludeInSitemap], [AccessibleWhenStoreClosed], [LimitedToStores], [IncludeInFooterColumn1], [IncludeInFooterColumn2], [IncludeInFooterColumn3], [IncludeInTopMenu], [IsPasswordProtected], [DisplayOrder] , [Title], [Body]) VALUES (N'ApplyVendor', 0, 0, 0, 0, 0, 0, 0, 0, 0, 1, N'', N'

Put your apply vendor instructions here. You can edit this in the admin site.

') END GO --'New vendor account submitted' message template IF NOT EXISTS ( SELECT 1 FROM [MessageTemplate] WHERE [Name] = N'VendorAccountApply.StoreOwnerNotification') BEGIN INSERT [MessageTemplate] ([Name], [BccEmailAddresses], [Subject], [Body], [IsActive], [EmailAccountId], [LimitedToStores], [AttachedDownloadId]) VALUES (N'VendorAccountApply.StoreOwnerNotification', null, N'%Store.Name%. New vendor account submitted.', N'

%Store.Name%

%Customer.FullName% (%Customer.Email%) has just submitted for a vendor account. Details are below:
Vendor name: %Vendor.Name%
Vendor email: %Vendor.Email%

You can activate it in admin area.

', 1, 0, 0, 0) END GO --new column IF NOT EXISTS (SELECT 1 FROM sys.columns WHERE object_id=object_id('[RewardPointsHistory]') and NAME='StoreId') BEGIN ALTER TABLE [RewardPointsHistory] ADD [StoreId] int NULL END GO --just use the first store --we cannot find original store IDs of some orders --furthermore, it won't work for points granted for registration (if enabled) UPDATE [RewardPointsHistory] SET [StoreId] = (SELECT TOP 1 [Id] from [Store]) WHERE [StoreId] IS NULL GO ALTER TABLE [RewardPointsHistory] ALTER COLUMN [StoreId] int NOT NULL GO --new setting IF NOT EXISTS (SELECT 1 FROM [Setting] WHERE [name] = N'rewardpointssettings.pointsaccumulatedforallstores') BEGIN INSERT [Setting] ([Name], [Value], [StoreId]) VALUES (N'rewardpointssettings.pointsaccumulatedforallstores', N'true', 0) END GO --new setting IF NOT EXISTS (SELECT 1 FROM [Setting] WHERE [name] = N'catalogsettings.allowviewunpublishedproductpage') BEGIN INSERT [Setting] ([Name], [Value], [StoreId]) VALUES (N'catalogsettings.allowviewunpublishedproductpage', N'true', 0) END GO --'Order refunded' message template IF NOT EXISTS ( SELECT 1 FROM [MessageTemplate] WHERE [Name] = N'OrderRefunded.StoreOwnerNotification') BEGIN INSERT [MessageTemplate] ([Name], [BccEmailAddresses], [Subject], [Body], [IsActive], [EmailAccountId], [LimitedToStores], [AttachedDownloadId]) VALUES (N'OrderRefunded.StoreOwnerNotification', null, N'%Store.Name%. Order #%Order.OrderNumber% refunded', N'

%Store.Name%

Order #%Order.OrderNumber% has been just refunded

Amount refunded: %Order.AmountRefunded%

Date Ordered: %Order.CreatedOn%

', 0, 0, 0, 0) END GO --new column IF NOT EXISTS (SELECT 1 FROM sys.columns WHERE object_id=object_id('[Topic]') and NAME='SubjectToAcl') BEGIN ALTER TABLE [Topic] ADD [SubjectToAcl] bit NULL END GO UPDATE [Topic] SET [SubjectToAcl] = 0 WHERE [SubjectToAcl] IS NULL GO ALTER TABLE [Topic] ALTER COLUMN [SubjectToAcl] bit NOT NULL GO --new column IF NOT EXISTS (SELECT 1 FROM sys.columns WHERE object_id=object_id('[ScheduleTask]') and NAME='LeasedByMachineName') BEGIN ALTER TABLE [ScheduleTask] ADD [LeasedByMachineName] nvarchar(MAX) NULL END GO --new column IF NOT EXISTS (SELECT 1 FROM sys.columns WHERE object_id=object_id('[ScheduleTask]') and NAME='LeasedUntilUtc') BEGIN ALTER TABLE [ScheduleTask] ADD [LeasedUntilUtc] datetime NULL END GO --new column IF NOT EXISTS (SELECT 1 FROM sys.columns WHERE object_id=object_id('[Product_ProductAttribute_Mapping]') and NAME='ConditionAttributeXml') BEGIN ALTER TABLE [Product_ProductAttribute_Mapping] ADD [ConditionAttributeXml] nvarchar(MAX) NULL END GO --delete setting DELETE FROM [Setting] WHERE [name] = N'catalogsettings.dynamicpriceupdateajax' GO --delete setting DELETE FROM [Setting] WHERE [name] = N'catalogsettings.enabledynamicpriceupdate' GO --new setting IF NOT EXISTS (SELECT 1 FROM [Setting] WHERE [name] = N'catalogsettings.ajaxprocessattributechange') BEGIN INSERT [Setting] ([Name], [Value], [StoreId]) VALUES (N'catalogsettings.ajaxprocessattributechange', N'true', 0) END GO --new setting IF NOT EXISTS (SELECT 1 FROM [Setting] WHERE [name] = N'ordersettings.minordersubtotalamountincludingtax') BEGIN INSERT [Setting] ([Name], [Value], [StoreId]) VALUES (N'ordersettings.minordersubtotalamountincludingtax', N'false', 0) END GO --new column IF NOT EXISTS (SELECT 1 FROM sys.columns WHERE object_id=object_id('[Product]') and NAME='MarkAsNew') BEGIN ALTER TABLE [Product] ADD [MarkAsNew] bit NULL END GO UPDATE [Product] SET [MarkAsNew] = 0 WHERE [MarkAsNew] IS NULL GO ALTER TABLE [Product] ALTER COLUMN [MarkAsNew] bit NOT NULL GO --new column IF NOT EXISTS (SELECT 1 FROM sys.columns WHERE object_id=object_id('[Product]') and NAME='MarkAsNewStartDateTimeUtc') BEGIN ALTER TABLE [Product] ADD [MarkAsNewStartDateTimeUtc] datetime NULL END GO --new column IF NOT EXISTS (SELECT 1 FROM sys.columns WHERE object_id=object_id('[Product]') and NAME='MarkAsNewEndDateTimeUtc') BEGIN ALTER TABLE [Product] ADD [MarkAsNewEndDateTimeUtc] datetime NULL END GO --a stored procedure update IF EXISTS ( SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'[ProductLoadAllPaged]') AND OBJECTPROPERTY(object_id,N'IsProcedure') = 1) DROP PROCEDURE [ProductLoadAllPaged] GO CREATE PROCEDURE [dbo].[ProductLoadAllPaged] ( @CategoryIds nvarchar(MAX) = null, --a list of category IDs (comma-separated list). e.g. 1,2,3 @ManufacturerId int = 0, @StoreId int = 0, @VendorId int = 0, @WarehouseId int = 0, @ProductTypeId int = null, --product type identifier, null - load all products @VisibleIndividuallyOnly bit = 0, --0 - load all products , 1 - "visible indivially" only @MarkedAsNewOnly bit = 0, --0 - load all products , 1 - "marked as new" only @ProductTagId int = 0, @FeaturedProducts bit = null, --0 featured only , 1 not featured only, null - load all products @PriceMin decimal(18, 4) = null, @PriceMax decimal(18, 4) = null, @Keywords nvarchar(4000) = null, @SearchDescriptions bit = 0, --a value indicating whether to search by a specified "keyword" in product descriptions @SearchSku bit = 0, --a value indicating whether to search by a specified "keyword" in product SKU @SearchProductTags bit = 0, --a value indicating whether to search by a specified "keyword" in product tags @UseFullTextSearch bit = 0, @FullTextMode int = 0, --0 - using CONTAINS with , 5 - using CONTAINS and OR with , 10 - using CONTAINS and AND with @FilteredSpecs nvarchar(MAX) = null, --filter by attributes (comma-separated list). e.g. 14,15,16 @LanguageId int = 0, @OrderBy int = 0, --0 - position, 5 - Name: A to Z, 6 - Name: Z to A, 10 - Price: Low to High, 11 - Price: High to Low, 15 - creation date @AllowedCustomerRoleIds nvarchar(MAX) = null, --a list of customer role IDs (comma-separated list) for which a product should be shown (if a subjet to ACL) @PageIndex int = 0, @PageSize int = 2147483644, @ShowHidden bit = 0, @OverridePublished bit = null, --null - process "Published" property according to "showHidden" parameter, true - load only "Published" products, false - load only "Unpublished" products @LoadFilterableSpecificationAttributeOptionIds bit = 0, --a value indicating whether we should load the specification attribute option identifiers applied to loaded products (all pages) @FilterableSpecificationAttributeOptionIds nvarchar(MAX) = null OUTPUT, --the specification attribute option identifiers applied to loaded products (all pages). returned as a comma separated list of identifiers @TotalRecords int = null OUTPUT ) AS BEGIN /* Products that filtered by keywords */ CREATE TABLE #KeywordProducts ( [ProductId] int NOT NULL ) DECLARE @SearchKeywords bit, @sql nvarchar(max), @sql_orderby nvarchar(max) SET NOCOUNT ON --filter by keywords SET @Keywords = isnull(@Keywords, '') SET @Keywords = rtrim(ltrim(@Keywords)) IF ISNULL(@Keywords, '') != '' BEGIN SET @SearchKeywords = 1 IF @UseFullTextSearch = 1 BEGIN --remove wrong chars (' ") SET @Keywords = REPLACE(@Keywords, '''', '') SET @Keywords = REPLACE(@Keywords, '"', '') --full-text search IF @FullTextMode = 0 BEGIN --0 - using CONTAINS with SET @Keywords = ' "' + @Keywords + '*" ' END ELSE BEGIN --5 - using CONTAINS and OR with --10 - using CONTAINS and AND with --clean multiple spaces WHILE CHARINDEX(' ', @Keywords) > 0 SET @Keywords = REPLACE(@Keywords, ' ', ' ') DECLARE @concat_term nvarchar(100) IF @FullTextMode = 5 --5 - using CONTAINS and OR with BEGIN SET @concat_term = 'OR' END IF @FullTextMode = 10 --10 - using CONTAINS and AND with BEGIN SET @concat_term = 'AND' END --now let's build search string declare @fulltext_keywords nvarchar(4000) set @fulltext_keywords = N'' declare @index int set @index = CHARINDEX(' ', @Keywords, 0) -- if index = 0, then only one field was passed IF(@index = 0) set @fulltext_keywords = ' "' + @Keywords + '*" ' ELSE BEGIN DECLARE @first BIT SET @first = 1 WHILE @index > 0 BEGIN IF (@first = 0) SET @fulltext_keywords = @fulltext_keywords + ' ' + @concat_term + ' ' ELSE SET @first = 0 SET @fulltext_keywords = @fulltext_keywords + '"' + SUBSTRING(@Keywords, 1, @index - 1) + '*"' SET @Keywords = SUBSTRING(@Keywords, @index + 1, LEN(@Keywords) - @index) SET @index = CHARINDEX(' ', @Keywords, 0) end -- add the last field IF LEN(@fulltext_keywords) > 0 SET @fulltext_keywords = @fulltext_keywords + ' ' + @concat_term + ' ' + '"' + SUBSTRING(@Keywords, 1, LEN(@Keywords)) + '*"' END SET @Keywords = @fulltext_keywords END END ELSE BEGIN --usual search by PATINDEX SET @Keywords = '%' + @Keywords + '%' END --PRINT @Keywords --product name SET @sql = ' INSERT INTO #KeywordProducts ([ProductId]) SELECT p.Id FROM Product p with (NOLOCK) WHERE ' IF @UseFullTextSearch = 1 SET @sql = @sql + 'CONTAINS(p.[Name], @Keywords) ' ELSE SET @sql = @sql + 'PATINDEX(@Keywords, p.[Name]) > 0 ' --localized product name SET @sql = @sql + ' UNION SELECT lp.EntityId FROM LocalizedProperty lp with (NOLOCK) WHERE lp.LocaleKeyGroup = N''Product'' AND lp.LanguageId = ' + ISNULL(CAST(@LanguageId AS nvarchar(max)), '0') + ' AND lp.LocaleKey = N''Name''' IF @UseFullTextSearch = 1 SET @sql = @sql + ' AND CONTAINS(lp.[LocaleValue], @Keywords) ' ELSE SET @sql = @sql + ' AND PATINDEX(@Keywords, lp.[LocaleValue]) > 0 ' IF @SearchDescriptions = 1 BEGIN --product short description SET @sql = @sql + ' UNION SELECT p.Id FROM Product p with (NOLOCK) WHERE ' IF @UseFullTextSearch = 1 SET @sql = @sql + 'CONTAINS(p.[ShortDescription], @Keywords) ' ELSE SET @sql = @sql + 'PATINDEX(@Keywords, p.[ShortDescription]) > 0 ' --product full description SET @sql = @sql + ' UNION SELECT p.Id FROM Product p with (NOLOCK) WHERE ' IF @UseFullTextSearch = 1 SET @sql = @sql + 'CONTAINS(p.[FullDescription], @Keywords) ' ELSE SET @sql = @sql + 'PATINDEX(@Keywords, p.[FullDescription]) > 0 ' --localized product short description SET @sql = @sql + ' UNION SELECT lp.EntityId FROM LocalizedProperty lp with (NOLOCK) WHERE lp.LocaleKeyGroup = N''Product'' AND lp.LanguageId = ' + ISNULL(CAST(@LanguageId AS nvarchar(max)), '0') + ' AND lp.LocaleKey = N''ShortDescription''' IF @UseFullTextSearch = 1 SET @sql = @sql + ' AND CONTAINS(lp.[LocaleValue], @Keywords) ' ELSE SET @sql = @sql + ' AND PATINDEX(@Keywords, lp.[LocaleValue]) > 0 ' --localized product full description SET @sql = @sql + ' UNION SELECT lp.EntityId FROM LocalizedProperty lp with (NOLOCK) WHERE lp.LocaleKeyGroup = N''Product'' AND lp.LanguageId = ' + ISNULL(CAST(@LanguageId AS nvarchar(max)), '0') + ' AND lp.LocaleKey = N''FullDescription''' IF @UseFullTextSearch = 1 SET @sql = @sql + ' AND CONTAINS(lp.[LocaleValue], @Keywords) ' ELSE SET @sql = @sql + ' AND PATINDEX(@Keywords, lp.[LocaleValue]) > 0 ' END --SKU IF @SearchSku = 1 BEGIN SET @sql = @sql + ' UNION SELECT p.Id FROM Product p with (NOLOCK) WHERE ' IF @UseFullTextSearch = 1 SET @sql = @sql + 'CONTAINS(p.[Sku], @Keywords) ' ELSE SET @sql = @sql + 'PATINDEX(@Keywords, p.[Sku]) > 0 ' END IF @SearchProductTags = 1 BEGIN --product tag SET @sql = @sql + ' UNION SELECT pptm.Product_Id FROM Product_ProductTag_Mapping pptm with(NOLOCK) INNER JOIN ProductTag pt with(NOLOCK) ON pt.Id = pptm.ProductTag_Id WHERE ' IF @UseFullTextSearch = 1 SET @sql = @sql + 'CONTAINS(pt.[Name], @Keywords) ' ELSE SET @sql = @sql + 'PATINDEX(@Keywords, pt.[Name]) > 0 ' --localized product tag SET @sql = @sql + ' UNION SELECT pptm.Product_Id FROM LocalizedProperty lp with (NOLOCK) INNER JOIN Product_ProductTag_Mapping pptm with(NOLOCK) ON lp.EntityId = pptm.ProductTag_Id WHERE lp.LocaleKeyGroup = N''ProductTag'' AND lp.LanguageId = ' + ISNULL(CAST(@LanguageId AS nvarchar(max)), '0') + ' AND lp.LocaleKey = N''Name''' IF @UseFullTextSearch = 1 SET @sql = @sql + ' AND CONTAINS(lp.[LocaleValue], @Keywords) ' ELSE SET @sql = @sql + ' AND PATINDEX(@Keywords, lp.[LocaleValue]) > 0 ' END --PRINT (@sql) EXEC sp_executesql @sql, N'@Keywords nvarchar(4000)', @Keywords END ELSE BEGIN SET @SearchKeywords = 0 END --filter by category IDs SET @CategoryIds = isnull(@CategoryIds, '') CREATE TABLE #FilteredCategoryIds ( CategoryId int not null ) INSERT INTO #FilteredCategoryIds (CategoryId) SELECT CAST(data as int) FROM [nop_splitstring_to_table](@CategoryIds, ',') DECLARE @CategoryIdsCount int SET @CategoryIdsCount = (SELECT COUNT(1) FROM #FilteredCategoryIds) --filter by attributes SET @FilteredSpecs = isnull(@FilteredSpecs, '') CREATE TABLE #FilteredSpecs ( SpecificationAttributeOptionId int not null ) INSERT INTO #FilteredSpecs (SpecificationAttributeOptionId) SELECT CAST(data as int) FROM [nop_splitstring_to_table](@FilteredSpecs, ',') DECLARE @SpecAttributesCount int SET @SpecAttributesCount = (SELECT COUNT(1) FROM #FilteredSpecs) --filter by customer role IDs (access control list) SET @AllowedCustomerRoleIds = isnull(@AllowedCustomerRoleIds, '') CREATE TABLE #FilteredCustomerRoleIds ( CustomerRoleId int not null ) INSERT INTO #FilteredCustomerRoleIds (CustomerRoleId) SELECT CAST(data as int) FROM [nop_splitstring_to_table](@AllowedCustomerRoleIds, ',') --paging DECLARE @PageLowerBound int DECLARE @PageUpperBound int DECLARE @RowsToReturn int SET @RowsToReturn = @PageSize * (@PageIndex + 1) SET @PageLowerBound = @PageSize * @PageIndex SET @PageUpperBound = @PageLowerBound + @PageSize + 1 CREATE TABLE #DisplayOrderTmp ( [Id] int IDENTITY (1, 1) NOT NULL, [ProductId] int NOT NULL ) SET @sql = ' INSERT INTO #DisplayOrderTmp ([ProductId]) SELECT p.Id FROM Product p with (NOLOCK)' IF @CategoryIdsCount > 0 BEGIN SET @sql = @sql + ' LEFT JOIN Product_Category_Mapping pcm with (NOLOCK) ON p.Id = pcm.ProductId' END IF @ManufacturerId > 0 BEGIN SET @sql = @sql + ' LEFT JOIN Product_Manufacturer_Mapping pmm with (NOLOCK) ON p.Id = pmm.ProductId' END IF ISNULL(@ProductTagId, 0) != 0 BEGIN SET @sql = @sql + ' LEFT JOIN Product_ProductTag_Mapping pptm with (NOLOCK) ON p.Id = pptm.Product_Id' END --searching by keywords IF @SearchKeywords = 1 BEGIN SET @sql = @sql + ' JOIN #KeywordProducts kp ON p.Id = kp.ProductId' END SET @sql = @sql + ' WHERE p.Deleted = 0' --filter by category IF @CategoryIdsCount > 0 BEGIN SET @sql = @sql + ' AND pcm.CategoryId IN (SELECT CategoryId FROM #FilteredCategoryIds)' IF @FeaturedProducts IS NOT NULL BEGIN SET @sql = @sql + ' AND pcm.IsFeaturedProduct = ' + CAST(@FeaturedProducts AS nvarchar(max)) END END --filter by manufacturer IF @ManufacturerId > 0 BEGIN SET @sql = @sql + ' AND pmm.ManufacturerId = ' + CAST(@ManufacturerId AS nvarchar(max)) IF @FeaturedProducts IS NOT NULL BEGIN SET @sql = @sql + ' AND pmm.IsFeaturedProduct = ' + CAST(@FeaturedProducts AS nvarchar(max)) END END --filter by vendor IF @VendorId > 0 BEGIN SET @sql = @sql + ' AND p.VendorId = ' + CAST(@VendorId AS nvarchar(max)) END --filter by warehouse IF @WarehouseId > 0 BEGIN --we should also ensure that 'ManageInventoryMethodId' is set to 'ManageStock' (1) --but we skip it in order to prevent hard-coded values (e.g. 1) and for better performance SET @sql = @sql + ' AND ( (p.UseMultipleWarehouses = 0 AND p.WarehouseId = ' + CAST(@WarehouseId AS nvarchar(max)) + ') OR (p.UseMultipleWarehouses > 0 AND EXISTS (SELECT 1 FROM ProductWarehouseInventory [pwi] WHERE [pwi].WarehouseId = ' + CAST(@WarehouseId AS nvarchar(max)) + ' AND [pwi].ProductId = p.Id)) )' END --filter by product type IF @ProductTypeId is not null BEGIN SET @sql = @sql + ' AND p.ProductTypeId = ' + CAST(@ProductTypeId AS nvarchar(max)) END --filter by "visible individually" IF @VisibleIndividuallyOnly = 1 BEGIN SET @sql = @sql + ' AND p.VisibleIndividually = 1' END --filter by "marked as new" IF @MarkedAsNewOnly = 1 BEGIN SET @sql = @sql + ' AND p.MarkAsNew = 1 AND (getutcdate() BETWEEN ISNULL(p.MarkAsNewStartDateTimeUtc, ''1/1/1900'') and ISNULL(p.MarkAsNewEndDateTimeUtc, ''1/1/2999''))' END --filter by product tag IF ISNULL(@ProductTagId, 0) != 0 BEGIN SET @sql = @sql + ' AND pptm.ProductTag_Id = ' + CAST(@ProductTagId AS nvarchar(max)) END --"Published" property IF (@OverridePublished is null) BEGIN --process according to "showHidden" IF @ShowHidden = 0 BEGIN SET @sql = @sql + ' AND p.Published = 1' END END ELSE IF (@OverridePublished = 1) BEGIN --published only SET @sql = @sql + ' AND p.Published = 1' END ELSE IF (@OverridePublished = 0) BEGIN --unpublished only SET @sql = @sql + ' AND p.Published = 0' END --show hidden IF @ShowHidden = 0 BEGIN SET @sql = @sql + ' AND p.Deleted = 0 AND (getutcdate() BETWEEN ISNULL(p.AvailableStartDateTimeUtc, ''1/1/1900'') and ISNULL(p.AvailableEndDateTimeUtc, ''1/1/2999''))' END --min price IF @PriceMin is not null BEGIN SET @sql = @sql + ' AND ( ( --special price (specified price and valid date range) (p.SpecialPrice IS NOT NULL AND (getutcdate() BETWEEN isnull(p.SpecialPriceStartDateTimeUtc, ''1/1/1900'') AND isnull(p.SpecialPriceEndDateTimeUtc, ''1/1/2999''))) AND (p.SpecialPrice >= ' + CAST(@PriceMin AS nvarchar(max)) + ') ) OR ( --regular price (price isnt specified or date range isnt valid) (p.SpecialPrice IS NULL OR (getutcdate() NOT BETWEEN isnull(p.SpecialPriceStartDateTimeUtc, ''1/1/1900'') AND isnull(p.SpecialPriceEndDateTimeUtc, ''1/1/2999''))) AND (p.Price >= ' + CAST(@PriceMin AS nvarchar(max)) + ') ) )' END --max price IF @PriceMax is not null BEGIN SET @sql = @sql + ' AND ( ( --special price (specified price and valid date range) (p.SpecialPrice IS NOT NULL AND (getutcdate() BETWEEN isnull(p.SpecialPriceStartDateTimeUtc, ''1/1/1900'') AND isnull(p.SpecialPriceEndDateTimeUtc, ''1/1/2999''))) AND (p.SpecialPrice <= ' + CAST(@PriceMax AS nvarchar(max)) + ') ) OR ( --regular price (price isnt specified or date range isnt valid) (p.SpecialPrice IS NULL OR (getutcdate() NOT BETWEEN isnull(p.SpecialPriceStartDateTimeUtc, ''1/1/1900'') AND isnull(p.SpecialPriceEndDateTimeUtc, ''1/1/2999''))) AND (p.Price <= ' + CAST(@PriceMax AS nvarchar(max)) + ') ) )' END --show hidden and ACL IF @ShowHidden = 0 BEGIN SET @sql = @sql + ' AND (p.SubjectToAcl = 0 OR EXISTS ( SELECT 1 FROM #FilteredCustomerRoleIds [fcr] WHERE [fcr].CustomerRoleId IN ( SELECT [acl].CustomerRoleId FROM [AclRecord] acl with (NOLOCK) WHERE [acl].EntityId = p.Id AND [acl].EntityName = ''Product'' ) ))' END --show hidden and filter by store IF @StoreId > 0 BEGIN SET @sql = @sql + ' AND (p.LimitedToStores = 0 OR EXISTS ( SELECT 1 FROM [StoreMapping] sm with (NOLOCK) WHERE [sm].EntityId = p.Id AND [sm].EntityName = ''Product'' and [sm].StoreId=' + CAST(@StoreId AS nvarchar(max)) + ' ))' END --filter by specs IF @SpecAttributesCount > 0 BEGIN SET @sql = @sql + ' AND NOT EXISTS ( SELECT 1 FROM #FilteredSpecs [fs] WHERE [fs].SpecificationAttributeOptionId NOT IN ( SELECT psam.SpecificationAttributeOptionId FROM Product_SpecificationAttribute_Mapping psam with (NOLOCK) WHERE psam.AllowFiltering = 1 AND psam.ProductId = p.Id ) )' END --sorting SET @sql_orderby = '' IF @OrderBy = 5 /* Name: A to Z */ SET @sql_orderby = ' p.[Name] ASC' ELSE IF @OrderBy = 6 /* Name: Z to A */ SET @sql_orderby = ' p.[Name] DESC' ELSE IF @OrderBy = 10 /* Price: Low to High */ SET @sql_orderby = ' p.[Price] ASC' ELSE IF @OrderBy = 11 /* Price: High to Low */ SET @sql_orderby = ' p.[Price] DESC' ELSE IF @OrderBy = 15 /* creation date */ SET @sql_orderby = ' p.[CreatedOnUtc] DESC' ELSE /* default sorting, 0 (position) */ BEGIN --category position (display order) IF @CategoryIdsCount > 0 SET @sql_orderby = ' pcm.DisplayOrder ASC' --manufacturer position (display order) IF @ManufacturerId > 0 BEGIN IF LEN(@sql_orderby) > 0 SET @sql_orderby = @sql_orderby + ', ' SET @sql_orderby = @sql_orderby + ' pmm.DisplayOrder ASC' END --name IF LEN(@sql_orderby) > 0 SET @sql_orderby = @sql_orderby + ', ' SET @sql_orderby = @sql_orderby + ' p.[Name] ASC' END SET @sql = @sql + ' ORDER BY' + @sql_orderby --PRINT (@sql) EXEC sp_executesql @sql DROP TABLE #FilteredCategoryIds DROP TABLE #FilteredSpecs DROP TABLE #FilteredCustomerRoleIds DROP TABLE #KeywordProducts CREATE TABLE #PageIndex ( [IndexId] int IDENTITY (1, 1) NOT NULL, [ProductId] int NOT NULL ) INSERT INTO #PageIndex ([ProductId]) SELECT ProductId FROM #DisplayOrderTmp GROUP BY ProductId ORDER BY min([Id]) --total records SET @TotalRecords = @@rowcount DROP TABLE #DisplayOrderTmp --prepare filterable specification attribute option identifier (if requested) IF @LoadFilterableSpecificationAttributeOptionIds = 1 BEGIN CREATE TABLE #FilterableSpecs ( [SpecificationAttributeOptionId] int NOT NULL ) INSERT INTO #FilterableSpecs ([SpecificationAttributeOptionId]) SELECT DISTINCT [psam].SpecificationAttributeOptionId FROM [Product_SpecificationAttribute_Mapping] [psam] with (NOLOCK) WHERE [psam].[AllowFiltering] = 1 AND [psam].[ProductId] IN (SELECT [pi].ProductId FROM #PageIndex [pi]) --build comma separated list of filterable identifiers SELECT @FilterableSpecificationAttributeOptionIds = COALESCE(@FilterableSpecificationAttributeOptionIds + ',' , '') + CAST(SpecificationAttributeOptionId as nvarchar(4000)) FROM #FilterableSpecs DROP TABLE #FilterableSpecs END --return products SELECT TOP (@RowsToReturn) p.* FROM #PageIndex [pi] INNER JOIN Product p with (NOLOCK) on p.Id = [pi].[ProductId] WHERE [pi].IndexId > @PageLowerBound AND [pi].IndexId < @PageUpperBound ORDER BY [pi].IndexId DROP TABLE #PageIndex END GO --renamed settings UPDATE [Setting] SET [Name] = N'catalogsettings.newproductsnumber' WHERE [Name] = N'catalogsettings.recentlyaddedproductsnumber' GO UPDATE [Setting] SET [Name] = N'catalogsettings.newproductsenabled' WHERE [Name] = N'catalogsettings.recentlyaddedproductsenabled' GO --new column IF NOT EXISTS (SELECT 1 FROM sys.columns WHERE object_id=object_id('[Discount]') and NAME='AppliedToSubCategories') BEGIN ALTER TABLE [Discount] ADD [AppliedToSubCategories] bit NULL END GO UPDATE [Discount] SET [AppliedToSubCategories] = 0 WHERE [AppliedToSubCategories] IS NULL GO ALTER TABLE [Discount] ALTER COLUMN [AppliedToSubCategories] bit NOT NULL GO --drop column IF EXISTS (SELECT 1 FROM sys.columns WHERE object_id=object_id('[Category]') and NAME='HasDiscountsApplied') BEGIN ALTER TABLE [Category] DROP COLUMN [HasDiscountsApplied] END GO --drop column IF EXISTS (SELECT 1 FROM sys.columns WHERE object_id=object_id('[Manufacturer]') and NAME='HasDiscountsApplied') BEGIN ALTER TABLE [Manufacturer] DROP COLUMN [HasDiscountsApplied] END GO --new setting IF NOT EXISTS (SELECT 1 FROM [Setting] WHERE [name] = N'catalogsettings.publishbackproductwhencancellingorders') BEGIN INSERT [Setting] ([Name], [Value], [StoreId]) VALUES (N'catalogsettings.publishbackproductwhencancellingorders', N'false', 0) END GO --move return request actions to table (this way we can localize them) IF NOT EXISTS (SELECT 1 FROM sys.objects WHERE object_id = OBJECT_ID(N'[dbo].[ReturnRequestAction]') and OBJECTPROPERTY(object_id, N'IsUserTable') = 1) BEGIN CREATE TABLE [dbo].[ReturnRequestAction]( [Id] [int] IDENTITY(1,1) NOT NULL, [Name] [nvarchar](400) NOT NULL, [DisplayOrder] [int] NOT NULL PRIMARY KEY CLUSTERED ( [Id] ASC )WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ) DECLARE @ReturnRequestActions nvarchar(1000) SELECT @ReturnRequestActions = [Value] FROM [Setting] WHERE [name] = N'ordersettings.returnrequestactions' SET @ReturnRequestActions = isnull(@ReturnRequestActions, '') INSERT INTO [ReturnRequestAction] ([Name], [DisplayOrder]) SELECT [data], 1 FROM [nop_splitstring_to_table](@ReturnRequestActions, ',') DELETE FROM [Setting] WHERE [name] = N'ordersettings.returnrequestactions' END GO --move return request reasons to table (this way we can localize them) IF NOT EXISTS (SELECT 1 FROM sys.objects WHERE object_id = OBJECT_ID(N'[dbo].[ReturnRequestReason]') and OBJECTPROPERTY(object_id, N'IsUserTable') = 1) BEGIN CREATE TABLE [dbo].[ReturnRequestReason]( [Id] [int] IDENTITY(1,1) NOT NULL, [Name] [nvarchar](400) NOT NULL, [DisplayOrder] [int] NOT NULL PRIMARY KEY CLUSTERED ( [Id] ASC )WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ) DECLARE @ReturnRequestReasons nvarchar(1000) SELECT @ReturnRequestReasons = [Value] FROM [Setting] WHERE [name] = N'ordersettings.returnrequestreasons' SET @ReturnRequestReasons = isnull(@ReturnRequestReasons, '') INSERT INTO [ReturnRequestReason] ([Name], [DisplayOrder]) SELECT [data], 1 FROM [nop_splitstring_to_table](@ReturnRequestReasons, ',') DELETE FROM [Setting] WHERE [name] = N'ordersettings.returnrequestreasons' END GO --new setting IF NOT EXISTS (SELECT 1 FROM [Setting] WHERE [name] = N'storeinformationsettings.hidepoweredbynopCommerce') BEGIN INSERT [Setting] ([Name], [Value], [StoreId]) VALUES (N'storeinformationsettings.hidepoweredbynopCommerce', N'false', 0) END GO --update a state abbreviation UPDATE [StateProvince] SET [Abbreviation] = N'YT' WHERE [Name] = N'Yukon Territory' GO --new permission IF NOT EXISTS ( SELECT 1 FROM [dbo].[PermissionRecord] WHERE [SystemName] = N'AccessClosedStore') BEGIN INSERT [dbo].[PermissionRecord] ([Name], [SystemName], [Category]) VALUES (N'Public store. Access a closed store', N'AccessClosedStore', N'PublicStore') DECLARE @PermissionRecordId INT SET @PermissionRecordId = @@IDENTITY --add it to admin role by default DECLARE @AdminCustomerRoleId int SELECT @AdminCustomerRoleId = Id FROM [CustomerRole] WHERE IsSystemRole=1 and [SystemName] = N'Administrators' INSERT [dbo].[PermissionRecord_Role_Mapping] ([PermissionRecord_Id], [CustomerRole_Id]) VALUES (@PermissionRecordId, @AdminCustomerRoleId) END GO --delete setting DELETE FROM [Setting] WHERE [name] = N'storeinformationsettings.storeclosedallowforadmins' GO UPDATE [ScheduleTask] SET [Seconds] = 3600 WHERE [Type] = N'Nop.Services.Directory.UpdateExchangeRateTask, Nop.Services' GO --new setting IF NOT EXISTS (SELECT 1 FROM [Setting] WHERE [name] = N'catalogsettings.displaydiscontinuedmessageforunpublishedproducts') BEGIN INSERT [Setting] ([Name], [Value], [StoreId]) VALUES (N'catalogsettings.displaydiscontinuedmessageforunpublishedproducts', N'true', 0) END GO --new table IF NOT EXISTS (SELECT 1 FROM sys.objects WHERE object_id = OBJECT_ID(N'[dbo].[VendorNote]') and OBJECTPROPERTY(object_id, N'IsUserTable') = 1) BEGIN CREATE TABLE [dbo].[VendorNote]( [Id] [int] IDENTITY(1,1) NOT NULL, [VendorId] [int] NOT NULL, [Note] [nvarchar](MAX) NOT NULL, [CreatedOnUtc] [datetime] NOT NULL PRIMARY KEY CLUSTERED ( [Id] ASC )WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ) END GO IF EXISTS (SELECT 1 FROM sys.objects WHERE name = 'VendorNote_Vendor' AND parent_object_id = Object_id('VendorNote') AND Objectproperty(object_id,N'IsForeignKey') = 1) ALTER TABLE dbo.VendorNote DROP CONSTRAINT VendorNote_Vendor GO ALTER TABLE [dbo].[VendorNote] WITH CHECK ADD CONSTRAINT [VendorNote_Vendor] FOREIGN KEY([VendorId]) REFERENCES [dbo].[Vendor] ([Id]) ON DELETE CASCADE GO --updated a stored procedure ALTER PROCEDURE [dbo].[ProductLoadAllPaged] ( @CategoryIds nvarchar(MAX) = null, --a list of category IDs (comma-separated list). e.g. 1,2,3 @ManufacturerId int = 0, @StoreId int = 0, @VendorId int = 0, @WarehouseId int = 0, @ProductTypeId int = null, --product type identifier, null - load all products @VisibleIndividuallyOnly bit = 0, --0 - load all products , 1 - "visible indivially" only @MarkedAsNewOnly bit = 0, --0 - load all products , 1 - "marked as new" only @ProductTagId int = 0, @FeaturedProducts bit = null, --0 featured only , 1 not featured only, null - load all products @PriceMin decimal(18, 4) = null, @PriceMax decimal(18, 4) = null, @Keywords nvarchar(4000) = null, @SearchDescriptions bit = 0, --a value indicating whether to search by a specified "keyword" in product descriptions @SearchSku bit = 0, --a value indicating whether to search by a specified "keyword" in product SKU @SearchProductTags bit = 0, --a value indicating whether to search by a specified "keyword" in product tags @UseFullTextSearch bit = 0, @FullTextMode int = 0, --0 - using CONTAINS with , 5 - using CONTAINS and OR with , 10 - using CONTAINS and AND with @FilteredSpecs nvarchar(MAX) = null, --filter by specification attribute options (comma-separated list of IDs). e.g. 14,15,16 @LanguageId int = 0, @OrderBy int = 0, --0 - position, 5 - Name: A to Z, 6 - Name: Z to A, 10 - Price: Low to High, 11 - Price: High to Low, 15 - creation date @AllowedCustomerRoleIds nvarchar(MAX) = null, --a list of customer role IDs (comma-separated list) for which a product should be shown (if a subjet to ACL) @PageIndex int = 0, @PageSize int = 2147483644, @ShowHidden bit = 0, @OverridePublished bit = null, --null - process "Published" property according to "showHidden" parameter, true - load only "Published" products, false - load only "Unpublished" products @LoadFilterableSpecificationAttributeOptionIds bit = 0, --a value indicating whether we should load the specification attribute option identifiers applied to loaded products (all pages) @FilterableSpecificationAttributeOptionIds nvarchar(MAX) = null OUTPUT, --the specification attribute option identifiers applied to loaded products (all pages). returned as a comma separated list of identifiers @TotalRecords int = null OUTPUT ) AS BEGIN /* Products that filtered by keywords */ CREATE TABLE #KeywordProducts ( [ProductId] int NOT NULL ) DECLARE @SearchKeywords bit, @sql nvarchar(max), @sql_orderby nvarchar(max) SET NOCOUNT ON --filter by keywords SET @Keywords = isnull(@Keywords, '') SET @Keywords = rtrim(ltrim(@Keywords)) IF ISNULL(@Keywords, '') != '' BEGIN SET @SearchKeywords = 1 IF @UseFullTextSearch = 1 BEGIN --remove wrong chars (' ") SET @Keywords = REPLACE(@Keywords, '''', '') SET @Keywords = REPLACE(@Keywords, '"', '') --full-text search IF @FullTextMode = 0 BEGIN --0 - using CONTAINS with SET @Keywords = ' "' + @Keywords + '*" ' END ELSE BEGIN --5 - using CONTAINS and OR with --10 - using CONTAINS and AND with --clean multiple spaces WHILE CHARINDEX(' ', @Keywords) > 0 SET @Keywords = REPLACE(@Keywords, ' ', ' ') DECLARE @concat_term nvarchar(100) IF @FullTextMode = 5 --5 - using CONTAINS and OR with BEGIN SET @concat_term = 'OR' END IF @FullTextMode = 10 --10 - using CONTAINS and AND with BEGIN SET @concat_term = 'AND' END --now let's build search string declare @fulltext_keywords nvarchar(4000) set @fulltext_keywords = N'' declare @index int set @index = CHARINDEX(' ', @Keywords, 0) -- if index = 0, then only one field was passed IF(@index = 0) set @fulltext_keywords = ' "' + @Keywords + '*" ' ELSE BEGIN DECLARE @first BIT SET @first = 1 WHILE @index > 0 BEGIN IF (@first = 0) SET @fulltext_keywords = @fulltext_keywords + ' ' + @concat_term + ' ' ELSE SET @first = 0 SET @fulltext_keywords = @fulltext_keywords + '"' + SUBSTRING(@Keywords, 1, @index - 1) + '*"' SET @Keywords = SUBSTRING(@Keywords, @index + 1, LEN(@Keywords) - @index) SET @index = CHARINDEX(' ', @Keywords, 0) end -- add the last field IF LEN(@fulltext_keywords) > 0 SET @fulltext_keywords = @fulltext_keywords + ' ' + @concat_term + ' ' + '"' + SUBSTRING(@Keywords, 1, LEN(@Keywords)) + '*"' END SET @Keywords = @fulltext_keywords END END ELSE BEGIN --usual search by PATINDEX SET @Keywords = '%' + @Keywords + '%' END --PRINT @Keywords --product name SET @sql = ' INSERT INTO #KeywordProducts ([ProductId]) SELECT p.Id FROM Product p with (NOLOCK) WHERE ' IF @UseFullTextSearch = 1 SET @sql = @sql + 'CONTAINS(p.[Name], @Keywords) ' ELSE SET @sql = @sql + 'PATINDEX(@Keywords, p.[Name]) > 0 ' --localized product name SET @sql = @sql + ' UNION SELECT lp.EntityId FROM LocalizedProperty lp with (NOLOCK) WHERE lp.LocaleKeyGroup = N''Product'' AND lp.LanguageId = ' + ISNULL(CAST(@LanguageId AS nvarchar(max)), '0') + ' AND lp.LocaleKey = N''Name''' IF @UseFullTextSearch = 1 SET @sql = @sql + ' AND CONTAINS(lp.[LocaleValue], @Keywords) ' ELSE SET @sql = @sql + ' AND PATINDEX(@Keywords, lp.[LocaleValue]) > 0 ' IF @SearchDescriptions = 1 BEGIN --product short description SET @sql = @sql + ' UNION SELECT p.Id FROM Product p with (NOLOCK) WHERE ' IF @UseFullTextSearch = 1 SET @sql = @sql + 'CONTAINS(p.[ShortDescription], @Keywords) ' ELSE SET @sql = @sql + 'PATINDEX(@Keywords, p.[ShortDescription]) > 0 ' --product full description SET @sql = @sql + ' UNION SELECT p.Id FROM Product p with (NOLOCK) WHERE ' IF @UseFullTextSearch = 1 SET @sql = @sql + 'CONTAINS(p.[FullDescription], @Keywords) ' ELSE SET @sql = @sql + 'PATINDEX(@Keywords, p.[FullDescription]) > 0 ' --localized product short description SET @sql = @sql + ' UNION SELECT lp.EntityId FROM LocalizedProperty lp with (NOLOCK) WHERE lp.LocaleKeyGroup = N''Product'' AND lp.LanguageId = ' + ISNULL(CAST(@LanguageId AS nvarchar(max)), '0') + ' AND lp.LocaleKey = N''ShortDescription''' IF @UseFullTextSearch = 1 SET @sql = @sql + ' AND CONTAINS(lp.[LocaleValue], @Keywords) ' ELSE SET @sql = @sql + ' AND PATINDEX(@Keywords, lp.[LocaleValue]) > 0 ' --localized product full description SET @sql = @sql + ' UNION SELECT lp.EntityId FROM LocalizedProperty lp with (NOLOCK) WHERE lp.LocaleKeyGroup = N''Product'' AND lp.LanguageId = ' + ISNULL(CAST(@LanguageId AS nvarchar(max)), '0') + ' AND lp.LocaleKey = N''FullDescription''' IF @UseFullTextSearch = 1 SET @sql = @sql + ' AND CONTAINS(lp.[LocaleValue], @Keywords) ' ELSE SET @sql = @sql + ' AND PATINDEX(@Keywords, lp.[LocaleValue]) > 0 ' END --SKU IF @SearchSku = 1 BEGIN SET @sql = @sql + ' UNION SELECT p.Id FROM Product p with (NOLOCK) WHERE ' IF @UseFullTextSearch = 1 SET @sql = @sql + 'CONTAINS(p.[Sku], @Keywords) ' ELSE SET @sql = @sql + 'PATINDEX(@Keywords, p.[Sku]) > 0 ' END IF @SearchProductTags = 1 BEGIN --product tag SET @sql = @sql + ' UNION SELECT pptm.Product_Id FROM Product_ProductTag_Mapping pptm with(NOLOCK) INNER JOIN ProductTag pt with(NOLOCK) ON pt.Id = pptm.ProductTag_Id WHERE ' IF @UseFullTextSearch = 1 SET @sql = @sql + 'CONTAINS(pt.[Name], @Keywords) ' ELSE SET @sql = @sql + 'PATINDEX(@Keywords, pt.[Name]) > 0 ' --localized product tag SET @sql = @sql + ' UNION SELECT pptm.Product_Id FROM LocalizedProperty lp with (NOLOCK) INNER JOIN Product_ProductTag_Mapping pptm with(NOLOCK) ON lp.EntityId = pptm.ProductTag_Id WHERE lp.LocaleKeyGroup = N''ProductTag'' AND lp.LanguageId = ' + ISNULL(CAST(@LanguageId AS nvarchar(max)), '0') + ' AND lp.LocaleKey = N''Name''' IF @UseFullTextSearch = 1 SET @sql = @sql + ' AND CONTAINS(lp.[LocaleValue], @Keywords) ' ELSE SET @sql = @sql + ' AND PATINDEX(@Keywords, lp.[LocaleValue]) > 0 ' END --PRINT (@sql) EXEC sp_executesql @sql, N'@Keywords nvarchar(4000)', @Keywords END ELSE BEGIN SET @SearchKeywords = 0 END --filter by category IDs SET @CategoryIds = isnull(@CategoryIds, '') CREATE TABLE #FilteredCategoryIds ( CategoryId int not null ) INSERT INTO #FilteredCategoryIds (CategoryId) SELECT CAST(data as int) FROM [nop_splitstring_to_table](@CategoryIds, ',') DECLARE @CategoryIdsCount int SET @CategoryIdsCount = (SELECT COUNT(1) FROM #FilteredCategoryIds) --filter by customer role IDs (access control list) SET @AllowedCustomerRoleIds = isnull(@AllowedCustomerRoleIds, '') CREATE TABLE #FilteredCustomerRoleIds ( CustomerRoleId int not null ) INSERT INTO #FilteredCustomerRoleIds (CustomerRoleId) SELECT CAST(data as int) FROM [nop_splitstring_to_table](@AllowedCustomerRoleIds, ',') --paging DECLARE @PageLowerBound int DECLARE @PageUpperBound int DECLARE @RowsToReturn int SET @RowsToReturn = @PageSize * (@PageIndex + 1) SET @PageLowerBound = @PageSize * @PageIndex SET @PageUpperBound = @PageLowerBound + @PageSize + 1 CREATE TABLE #DisplayOrderTmp ( [Id] int IDENTITY (1, 1) NOT NULL, [ProductId] int NOT NULL ) SET @sql = ' INSERT INTO #DisplayOrderTmp ([ProductId]) SELECT p.Id FROM Product p with (NOLOCK)' IF @CategoryIdsCount > 0 BEGIN SET @sql = @sql + ' LEFT JOIN Product_Category_Mapping pcm with (NOLOCK) ON p.Id = pcm.ProductId' END IF @ManufacturerId > 0 BEGIN SET @sql = @sql + ' LEFT JOIN Product_Manufacturer_Mapping pmm with (NOLOCK) ON p.Id = pmm.ProductId' END IF ISNULL(@ProductTagId, 0) != 0 BEGIN SET @sql = @sql + ' LEFT JOIN Product_ProductTag_Mapping pptm with (NOLOCK) ON p.Id = pptm.Product_Id' END --searching by keywords IF @SearchKeywords = 1 BEGIN SET @sql = @sql + ' JOIN #KeywordProducts kp ON p.Id = kp.ProductId' END SET @sql = @sql + ' WHERE p.Deleted = 0' --filter by category IF @CategoryIdsCount > 0 BEGIN SET @sql = @sql + ' AND pcm.CategoryId IN (SELECT CategoryId FROM #FilteredCategoryIds)' IF @FeaturedProducts IS NOT NULL BEGIN SET @sql = @sql + ' AND pcm.IsFeaturedProduct = ' + CAST(@FeaturedProducts AS nvarchar(max)) END END --filter by manufacturer IF @ManufacturerId > 0 BEGIN SET @sql = @sql + ' AND pmm.ManufacturerId = ' + CAST(@ManufacturerId AS nvarchar(max)) IF @FeaturedProducts IS NOT NULL BEGIN SET @sql = @sql + ' AND pmm.IsFeaturedProduct = ' + CAST(@FeaturedProducts AS nvarchar(max)) END END --filter by vendor IF @VendorId > 0 BEGIN SET @sql = @sql + ' AND p.VendorId = ' + CAST(@VendorId AS nvarchar(max)) END --filter by warehouse IF @WarehouseId > 0 BEGIN --we should also ensure that 'ManageInventoryMethodId' is set to 'ManageStock' (1) --but we skip it in order to prevent hard-coded values (e.g. 1) and for better performance SET @sql = @sql + ' AND ( (p.UseMultipleWarehouses = 0 AND p.WarehouseId = ' + CAST(@WarehouseId AS nvarchar(max)) + ') OR (p.UseMultipleWarehouses > 0 AND EXISTS (SELECT 1 FROM ProductWarehouseInventory [pwi] WHERE [pwi].WarehouseId = ' + CAST(@WarehouseId AS nvarchar(max)) + ' AND [pwi].ProductId = p.Id)) )' END --filter by product type IF @ProductTypeId is not null BEGIN SET @sql = @sql + ' AND p.ProductTypeId = ' + CAST(@ProductTypeId AS nvarchar(max)) END --filter by "visible individually" IF @VisibleIndividuallyOnly = 1 BEGIN SET @sql = @sql + ' AND p.VisibleIndividually = 1' END --filter by "marked as new" IF @MarkedAsNewOnly = 1 BEGIN SET @sql = @sql + ' AND p.MarkAsNew = 1 AND (getutcdate() BETWEEN ISNULL(p.MarkAsNewStartDateTimeUtc, ''1/1/1900'') and ISNULL(p.MarkAsNewEndDateTimeUtc, ''1/1/2999''))' END --filter by product tag IF ISNULL(@ProductTagId, 0) != 0 BEGIN SET @sql = @sql + ' AND pptm.ProductTag_Id = ' + CAST(@ProductTagId AS nvarchar(max)) END --"Published" property IF (@OverridePublished is null) BEGIN --process according to "showHidden" IF @ShowHidden = 0 BEGIN SET @sql = @sql + ' AND p.Published = 1' END END ELSE IF (@OverridePublished = 1) BEGIN --published only SET @sql = @sql + ' AND p.Published = 1' END ELSE IF (@OverridePublished = 0) BEGIN --unpublished only SET @sql = @sql + ' AND p.Published = 0' END --show hidden IF @ShowHidden = 0 BEGIN SET @sql = @sql + ' AND p.Deleted = 0 AND (getutcdate() BETWEEN ISNULL(p.AvailableStartDateTimeUtc, ''1/1/1900'') and ISNULL(p.AvailableEndDateTimeUtc, ''1/1/2999''))' END --min price IF @PriceMin is not null BEGIN SET @sql = @sql + ' AND ( ( --special price (specified price and valid date range) (p.SpecialPrice IS NOT NULL AND (getutcdate() BETWEEN isnull(p.SpecialPriceStartDateTimeUtc, ''1/1/1900'') AND isnull(p.SpecialPriceEndDateTimeUtc, ''1/1/2999''))) AND (p.SpecialPrice >= ' + CAST(@PriceMin AS nvarchar(max)) + ') ) OR ( --regular price (price isnt specified or date range isnt valid) (p.SpecialPrice IS NULL OR (getutcdate() NOT BETWEEN isnull(p.SpecialPriceStartDateTimeUtc, ''1/1/1900'') AND isnull(p.SpecialPriceEndDateTimeUtc, ''1/1/2999''))) AND (p.Price >= ' + CAST(@PriceMin AS nvarchar(max)) + ') ) )' END --max price IF @PriceMax is not null BEGIN SET @sql = @sql + ' AND ( ( --special price (specified price and valid date range) (p.SpecialPrice IS NOT NULL AND (getutcdate() BETWEEN isnull(p.SpecialPriceStartDateTimeUtc, ''1/1/1900'') AND isnull(p.SpecialPriceEndDateTimeUtc, ''1/1/2999''))) AND (p.SpecialPrice <= ' + CAST(@PriceMax AS nvarchar(max)) + ') ) OR ( --regular price (price isnt specified or date range isnt valid) (p.SpecialPrice IS NULL OR (getutcdate() NOT BETWEEN isnull(p.SpecialPriceStartDateTimeUtc, ''1/1/1900'') AND isnull(p.SpecialPriceEndDateTimeUtc, ''1/1/2999''))) AND (p.Price <= ' + CAST(@PriceMax AS nvarchar(max)) + ') ) )' END --show hidden and ACL IF @ShowHidden = 0 BEGIN SET @sql = @sql + ' AND (p.SubjectToAcl = 0 OR EXISTS ( SELECT 1 FROM #FilteredCustomerRoleIds [fcr] WHERE [fcr].CustomerRoleId IN ( SELECT [acl].CustomerRoleId FROM [AclRecord] acl with (NOLOCK) WHERE [acl].EntityId = p.Id AND [acl].EntityName = ''Product'' ) ))' END --show hidden and filter by store IF @StoreId > 0 BEGIN SET @sql = @sql + ' AND (p.LimitedToStores = 0 OR EXISTS ( SELECT 1 FROM [StoreMapping] sm with (NOLOCK) WHERE [sm].EntityId = p.Id AND [sm].EntityName = ''Product'' and [sm].StoreId=' + CAST(@StoreId AS nvarchar(max)) + ' ))' END --filter by specification attribution options SET @FilteredSpecs = isnull(@FilteredSpecs, '') CREATE TABLE #FilteredSpecs ( SpecificationAttributeOptionId int not null ) INSERT INTO #FilteredSpecs (SpecificationAttributeOptionId) SELECT CAST(data as int) FROM [nop_splitstring_to_table](@FilteredSpecs, ',') DECLARE @SpecAttributesCount int SET @SpecAttributesCount = (SELECT COUNT(1) FROM #FilteredSpecs) IF @SpecAttributesCount > 0 BEGIN --do it for each specified specification option DECLARE @SpecificationAttributeOptionId int DECLARE cur_SpecificationAttributeOption CURSOR FOR SELECT [SpecificationAttributeOptionId] FROM [#FilteredSpecs] OPEN cur_SpecificationAttributeOption FETCH NEXT FROM cur_SpecificationAttributeOption INTO @SpecificationAttributeOptionId WHILE @@FETCH_STATUS = 0 BEGIN SET @sql = @sql + ' AND p.Id in (select psam.ProductId from [Product_SpecificationAttribute_Mapping] psam with (NOLOCK) where psam.AllowFiltering = 1 and psam.SpecificationAttributeOptionId = ' + CAST(@SpecificationAttributeOptionId AS nvarchar(max)) + ')' --fetch next identifier FETCH NEXT FROM cur_SpecificationAttributeOption INTO @SpecificationAttributeOptionId END CLOSE cur_SpecificationAttributeOption DEALLOCATE cur_SpecificationAttributeOption END --sorting SET @sql_orderby = '' IF @OrderBy = 5 /* Name: A to Z */ SET @sql_orderby = ' p.[Name] ASC' ELSE IF @OrderBy = 6 /* Name: Z to A */ SET @sql_orderby = ' p.[Name] DESC' ELSE IF @OrderBy = 10 /* Price: Low to High */ SET @sql_orderby = ' p.[Price] ASC' ELSE IF @OrderBy = 11 /* Price: High to Low */ SET @sql_orderby = ' p.[Price] DESC' ELSE IF @OrderBy = 15 /* creation date */ SET @sql_orderby = ' p.[CreatedOnUtc] DESC' ELSE /* default sorting, 0 (position) */ BEGIN --category position (display order) IF @CategoryIdsCount > 0 SET @sql_orderby = ' pcm.DisplayOrder ASC' --manufacturer position (display order) IF @ManufacturerId > 0 BEGIN IF LEN(@sql_orderby) > 0 SET @sql_orderby = @sql_orderby + ', ' SET @sql_orderby = @sql_orderby + ' pmm.DisplayOrder ASC' END --name IF LEN(@sql_orderby) > 0 SET @sql_orderby = @sql_orderby + ', ' SET @sql_orderby = @sql_orderby + ' p.[Name] ASC' END SET @sql = @sql + ' ORDER BY' + @sql_orderby --PRINT (@sql) EXEC sp_executesql @sql DROP TABLE #FilteredCategoryIds DROP TABLE #FilteredSpecs DROP TABLE #FilteredCustomerRoleIds DROP TABLE #KeywordProducts CREATE TABLE #PageIndex ( [IndexId] int IDENTITY (1, 1) NOT NULL, [ProductId] int NOT NULL ) INSERT INTO #PageIndex ([ProductId]) SELECT ProductId FROM #DisplayOrderTmp GROUP BY ProductId ORDER BY min([Id]) --total records SET @TotalRecords = @@rowcount DROP TABLE #DisplayOrderTmp --prepare filterable specification attribute option identifier (if requested) IF @LoadFilterableSpecificationAttributeOptionIds = 1 BEGIN CREATE TABLE #FilterableSpecs ( [SpecificationAttributeOptionId] int NOT NULL ) INSERT INTO #FilterableSpecs ([SpecificationAttributeOptionId]) SELECT DISTINCT [psam].SpecificationAttributeOptionId FROM [Product_SpecificationAttribute_Mapping] [psam] with (NOLOCK) WHERE [psam].[AllowFiltering] = 1 AND [psam].[ProductId] IN (SELECT [pi].ProductId FROM #PageIndex [pi]) --build comma separated list of filterable identifiers SELECT @FilterableSpecificationAttributeOptionIds = COALESCE(@FilterableSpecificationAttributeOptionIds + ',' , '') + CAST(SpecificationAttributeOptionId as nvarchar(4000)) FROM #FilterableSpecs DROP TABLE #FilterableSpecs END --return products SELECT TOP (@RowsToReturn) p.* FROM #PageIndex [pi] INNER JOIN Product p with (NOLOCK) on p.Id = [pi].[ProductId] WHERE [pi].IndexId > @PageLowerBound AND [pi].IndexId < @PageUpperBound ORDER BY [pi].IndexId DROP TABLE #PageIndex END GO --new setting IF NOT EXISTS (SELECT 1 FROM [Setting] WHERE [name] = N'pdfsettings.fontfilename') BEGIN INSERT [Setting] ([Name], [Value], [StoreId]) VALUES (N'pdfsettings.fontfilename', N'FreeSerif.ttf', 0) END GO