├── .gitignore ├── CODE_OF_CONDUCT.md ├── LICENSE ├── README.md ├── SECURITY.md ├── SUPPORT.md └── src ├── Indexes.txt ├── PLPgSQL ├── Scalar UDFs │ ├── Sudf_20b_GetManufactComplex.sql │ ├── proc62_totalCustLoss.sql │ ├── sudf_10_isListDistinct.sql │ ├── sudf_11_genRandomChar.sql │ ├── sudf_12_increaseInWebSpending.sql │ ├── sudf_13_maxPurchaseChannel.sql │ ├── sudf_14_sameManager.sql │ ├── sudf_15_incomeBandOfMaxBuy.sql │ ├── sudf_16_promoVsNoPromo.sql │ ├── sudf_17_preferredChannel_wrtCount.sql │ ├── sudf_18_preferredChannel_wrtExpenditure.sql │ ├── sudf_19_highDeficiencyAmount.sql │ ├── sudf_1_totalLargePurchases.sql │ ├── sudf_20a_GetManufactSimple.sql │ ├── sudf_2_maxPromoChannel.sql │ ├── sudf_3a_maxRetReasonWeb.sql │ ├── sudf_3b_maxRetReasonCat.sql │ ├── sudf_3c_maxRetReasonStore.sql │ ├── sudf_4_genRandomInt.sql │ ├── sudf_5_morEveRatio.sql │ ├── sudf_6_totalDiscount.sql │ ├── sudf_7_profitableManager.sql │ ├── sudf_8_maxRetClass.sql │ ├── sudf_9a_correlation_wealthShipCost_Catalog.sql │ └── sudf_9b_correlation_wealthShipCost_web.sql ├── Stored Procedures │ ├── proc10_remove_item.sql │ ├── proc11_repeatedShoppers.sql │ ├── proc12_returnReason_highlyEducated.sql │ ├── proc13_returnReason_lessEducated.sql │ ├── proc14_salePerBrandCatalog.sql │ ├── proc15_salePerBrandStore.sql │ ├── proc16_salePerBrandWeb.sql │ ├── proc17_saleShoppers.sql │ ├── proc18_updateItemPrice.sql │ ├── proc19_updateWebUrl.sql │ ├── proc1_custDemoSaleInfo.sql │ ├── proc20_warehouse_addressGet.sql │ ├── proc21_activatePromoCat.sql │ ├── proc22_activatePromoStore.sql │ ├── proc23_activatePromoWeb.sql │ ├── proc24_CreateRandmString.sql │ ├── proc25_delCatPage.sql │ ├── proc27_getStoreByManager.sql │ ├── proc28_insertCallCenter.sql │ ├── proc29_insertNewShipCarrier.sql │ ├── proc2_excessReturn_web.sql │ ├── proc30_lossByEdcated-Risky.sql │ ├── proc31_maxSaleElectronicsMonth.sql │ ├── proc32_maxSaleJewelryMonth.sql │ ├── proc33_newCatalogPage.sql │ ├── proc34_newPromotion.sql │ ├── proc35_newStore.sql │ ├── proc36_newWarehouse.sql │ ├── proc37_procesStoreReturn.sql │ ├── proc3_excessReturnCustInfo.sql │ ├── proc44_cusWithIncomeInRange.sql │ ├── proc45_moreOnlineThanStore.sql │ ├── proc46_processReturn.sql │ ├── proc4_getCustomerInfo.sql │ ├── proc52_catalogOrderCancellation.sql │ ├── proc57_webOrderCancellation.sql │ ├── proc58_getShipMode.sql │ ├── proc59_newCatSale.sql │ ├── proc5_getImmigrantCust.sql │ ├── proc60_newStoreSale.sql │ ├── proc61_newWebSale.sql │ ├── proc6_getNativeCust.sql │ ├── proc7_lowIncomeCustWithHighPurchase.sql │ └── proc9_popularWP.sql ├── Table Valued UDFs │ ├── TVF1_lateDeliveryStats.sql │ ├── TVF2_highreturnReasons.sql │ ├── TVF3_maxProfitsales.sql │ ├── TVF4a_bestpromoWeb.sql │ ├── TVF4b_bestPromoCatalog.sql │ ├── TVF4c_bestPromoStore.sql │ ├── TVF6_bestStoreForCategories.sql │ └── TVF7_profitMonitoring.sql └── Triggers │ ├── trig_1_DateTableInsert.sql │ ├── trig_2_CustAddressUpdate.sql │ ├── trig_3_PromoUpdate.sql │ ├── trig_4_ItemDeleteUpdate.sql │ ├── trig_5_CatPageDelete.sql │ └── trig_6_CustDelete.sql ├── PLSQL ├── Scalar UDFs │ ├── Sudf_20b_GetManufactComplex.sql │ ├── sudf_11_getRandomChar.sql │ ├── sudf_12_increaseInWebSpending.sql │ ├── sudf_13_maxPurchaseChannel.sql │ ├── sudf_15_incomebandOfMaxBuy.sql │ ├── sudf_16_promoVsNoPromo.sql │ ├── sudf_17_preferredChannel_wrtCount.sql │ ├── sudf_18_preferredChannel_wrtExpenditure.sql │ ├── sudf_1_totalLargePurchases.sql │ ├── sudf_20a_GetManufactSimple.sql │ ├── sudf_2_maxPromoChannel.sql │ ├── sudf_3a_maxRetReasonWeb.sql │ ├── sudf_3b_maxRetReasonCat.sql │ ├── sudf_3c_maxRetReasonStore.sql │ ├── sudf_4_getRandomInt.sql │ ├── sudf_5_MorEveRatio.sql │ ├── sudf_6_totalDiscount.sql │ ├── sudf_7_profitableManager.sql │ ├── sudf_8_maxReturnClass.sql │ ├── sudf_9a_correlation_wealthShipCost_catalog.sql │ └── sudf_9b_correlation_wealthShipCost_web.sql ├── Stored Procedures │ ├── proc10_remove_item.sql │ ├── proc11_repeatedShoppers.sql │ ├── proc12_returnReason_highlyEducated.sql │ ├── proc13_returnReason_lessEducated.sql │ ├── proc14_salePerBrandCatalog.sql │ ├── proc15_salePerBrandStore.sql │ ├── proc16_salePerBrandWeb.sql │ ├── proc17_saleShoppers.sql │ ├── proc18_updateItemPrice.sql │ ├── proc19_updateWebUrl.sql │ ├── proc1_custDemoSaleInfo.sql │ ├── proc21_activatePromoCat.sql │ ├── proc22_activatePromoStore.sql │ ├── proc23_activatePromoWeb.sql │ ├── proc24_CreateRandmString.sql │ ├── proc25_delCatPage.sql │ ├── proc26_getReturnReason.sql │ ├── proc27_getStoreByManager.sql │ ├── proc28_insertCallCenter.sql │ ├── proc29_insertNewShipCarrier.sql │ ├── proc2_excessReturn_web.sql │ ├── proc30_lossByEdcated-Risky.sql │ ├── proc31_maxSaleElectronicsMonth.sql │ ├── proc32_maxSaleJewelryMonth.sql │ ├── proc33_newCatalogPage.sql │ ├── proc34_newPromotion.sql │ ├── proc35_newStore.sql │ ├── proc36_newWarehouse.sql │ ├── proc37_procesStoreReturn.sql │ ├── proc3_excessReturnCustInfo.sql │ ├── proc44_cusWithIncomeInRange.sql │ ├── proc45_moreOnlineThanStore.sql │ ├── proc46_processReturn.sql │ ├── proc4_getCustomerInfo.sql │ ├── proc52_catalogOrderCancellation.sql │ ├── proc57_webOrderCancellation.sql │ ├── proc58_getShipMode.sql │ ├── proc59_newCatSale.sql │ ├── proc5_getImmigrantCust.sql │ ├── proc60_newStoreSale.sql │ ├── proc61_newWebSale.sql │ ├── proc62_totalCustLoss.sql │ ├── proc6_getNativeCust.sql │ ├── proc7_lowIncomeCustWithHighPurchase.sql │ └── proc9_popularWP.sql ├── Table Valued UDFs │ ├── TVF2_highReturnReason.sql │ ├── TVF3_maxProfitStates.sql │ ├── TVF4a_bestPromoWeb.sql │ ├── TVF4b_bestPromoCatalog.sql │ ├── TVF4c_bestPromoStore.sql │ ├── TVF6_bestStoreForCategories.sql │ └── TVF7_profitMonitoring.sql └── Triggers │ ├── trigger1_afterInsertdate.sql │ ├── trigger2_afterUpdateCA.sql │ ├── trigger3_afterUpdate_promo.sql │ ├── trigger4_upDelItem.sql │ ├── trigger5_afterdelCatPage.sql │ └── trigger6_afterDelCust.sql ├── SQL-ProcBench Schema.txt └── T-SQL ├── Scalar UDFs ├── Sudf_20b_GetManufactComplex.sql ├── sudf_10_isListDistinct.sql ├── sudf_11_genRandomChar.sql ├── sudf_12_increaseInWebSpending.sql ├── sudf_13_maxPurchaseChannel.sql ├── sudf_14_sameManager.sql ├── sudf_15_incomeBandOfMaxBuy.sql ├── sudf_16_promoVsNoPromo.sql ├── sudf_17_preferredChannel_wrtCount.sql ├── sudf_18_preferredChannel_wrtExpenditure.sql ├── sudf_19_highdeficiencyAmount.sql ├── sudf_1_totalLargePurchase.sql ├── sudf_20a_GetManufactSimple.sql ├── sudf_2_maxPromoChannel.sql ├── sudf_3a_maxRetReasonWeb.sql ├── sudf_3b_maxRetReasonCat.sql ├── sudf_3c_maxRetReasonStore.sql ├── sudf_4_getRandomInt.sql ├── sudf_5_morEveRatio.sql ├── sudf_6_totalDiscount.sql ├── sudf_7_profitableManager.sql ├── sudf_8_maxRetClass.sql ├── sudf_9a_correlation_wealthShipCost_Catalog.sql └── sudf_9b_correlation_wealthShipCost_web.sql ├── Stored Procedures ├── proc10_remove_item.sql ├── proc11_repeatedShoppers.sql ├── proc12_returnReason_highlyEducated.sql ├── proc13_returnReason_lessEducated.sql ├── proc14_salePerBrandCatalog.sql ├── proc15_salePerBrandStore.sql ├── proc16_salePerBrandWeb.sql ├── proc17_saleShoppers.sql ├── proc18_updateItemPrice.sql ├── proc19_updateWebUrl.sql ├── proc1_custDemoSaleInfo.sql ├── proc20_warehouse_addressGet.sql ├── proc21_activatePromoCat.sql ├── proc22_activatePromoStore.sql ├── proc23_activatePromoWeb.sql ├── proc24_CreateRandmString.sql ├── proc25_delCatPage.sql ├── proc26_getReturnReason.sql ├── proc27_getStoreByManager.sql ├── proc28_insertCallCenter.sql ├── proc29_insertNewShipCarrier.sql ├── proc2_excessReturn_web.sql ├── proc30_lossByEdcated-Risky.sql ├── proc31_maxSaleElectronicsMonth.sql ├── proc32_maxSaleJewelryMonth.sql ├── proc33_newCatalogPage.sql ├── proc34_newPromotion.sql ├── proc35_newStore.sql ├── proc36_newWarehouse.sql ├── proc37_procesStoreReturn.sql ├── proc38_removeObj.sql ├── proc39_removeObjIfExists.sql ├── proc3_excessReturnCustInfo.sql ├── proc40_renameObj.sql ├── proc41_renameUsingObjId.sql ├── proc42_totalInventoryDef.sql ├── proc43_DeleteCustomer.sql ├── proc44_cusWithIncomeInRange.sql ├── proc45_moreOnlineThanStore.sql ├── proc46_processReturn.sql ├── proc47_setPreferredCust.sql ├── proc48_unsatisfiedCustCat.sql ├── proc49_unsatisfiedCustsStore.sql ├── proc4_getCustomerInfo.sql ├── proc50_unsatisfiedWeb.sql ├── proc51_worstsellers.sql ├── proc52_catalogOrderCancellation.sql ├── proc53_shutOldCC.sql ├── proc54_trackSaleCat.sql ├── proc55_trackSaleStore.sql ├── proc56_trackSaleWeb.sql ├── proc57_webOrderCancellation.sql ├── proc58_getShipMode.sql ├── proc59_newCatSale.sql ├── proc5_getImmigrantCust.sql ├── proc60_newStoreSale.sql ├── proc61_newWebSale.sql ├── proc62_totalCustLoss.sql ├── proc63_accessItemQuality.sql ├── proc6_getNativeCust.sql ├── proc7_lowIncomeCustWithHighPurchase.sql ├── proc8_multiStateShoppers_2.sql └── proc9_popularWP.sql ├── Table Valued UDFs ├── TVF1_lateDeliveryStats.sql ├── TVF2_highreturnReasons.sql ├── TVF3_maxProfitsales.sql ├── TVF4a_bestpromoWeb.sql ├── TVF4b_bestPromoCatalog.sql ├── TVF4c_bestPromoStore.sql ├── TVF5-unemployedManager.sql ├── TVF6-bestStoreForCategories.sql ├── TVF7_profitMonitoring.sql └── TVF8_MaxReturnItems.sql └── Triggers ├── Trigger1_AfterInsert_dateTable.sql ├── Trigger2_afterUpdate_custAddress.sql ├── Trigger3_afterUpdate_promo.sql ├── Trigger4_delUp_item.sql ├── Trigger5_afterDelete_catPage.sql └── Trigger6_afterDelete_customer.sql /CODE_OF_CONDUCT.md: -------------------------------------------------------------------------------- 1 | # Microsoft Open Source Code of Conduct 2 | 3 | This project has adopted the [Microsoft Open Source Code of Conduct](https://opensource.microsoft.com/codeofconduct/). 4 | 5 | Resources: 6 | 7 | - [Microsoft Open Source Code of Conduct](https://opensource.microsoft.com/codeofconduct/) 8 | - [Microsoft Code of Conduct FAQ](https://opensource.microsoft.com/codeofconduct/faq/) 9 | - Contact [opencode@microsoft.com](mailto:opencode@microsoft.com) with questions or concerns 10 | -------------------------------------------------------------------------------- /LICENSE: -------------------------------------------------------------------------------- 1 | MIT License 2 | 3 | Copyright (c) Microsoft Corporation. 4 | 5 | Permission is hereby granted, free of charge, to any person obtaining a copy 6 | of this software and associated documentation files (the "Software"), to deal 7 | in the Software without restriction, including without limitation the rights 8 | to use, copy, modify, merge, publish, distribute, sublicense, and/or sell 9 | copies of the Software, and to permit persons to whom the Software is 10 | furnished to do so, subject to the following conditions: 11 | 12 | The above copyright notice and this permission notice shall be included in all 13 | copies or substantial portions of the Software. 14 | 15 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR 16 | IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, 17 | FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE 18 | AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER 19 | LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, 20 | OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE 21 | SOFTWARE 22 | -------------------------------------------------------------------------------- /SUPPORT.md: -------------------------------------------------------------------------------- 1 | # Support 2 | 3 | ## How to file issues and get help 4 | 5 | This project uses GitHub Issues to track bugs and feature requests. Please search the existing 6 | issues before filing new issues to avoid duplicates. For new issues, file your bug or 7 | feature request as a new Issue. 8 | 9 | For help and questions about using this project, please email karam\[at\]microsoft\[dot\]com. 10 | 11 | ## Microsoft Support Policy 12 | 13 | Support for this **PROJECT or PRODUCT** is limited to the resources listed above. 14 | -------------------------------------------------------------------------------- /src/Indexes.txt: -------------------------------------------------------------------------------- 1 | Index Creation Statements (in T-SQL) 2 | 3 | 1) clustered columnstore indexes for history tables. 4 | CREATE CLUSTERED COLUMNSTORE INDEX cci_ws ON web_sales_history; 5 | CREATE CLUSTERED COLUMNSTORE INDEX cci_wrh ON web_returns_history; 6 | CREATE CLUSTERED COLUMNSTORE INDEX cci_cs ON catalog_sales_history; 7 | CREATE CLUSTERED COLUMNSTORE INDEX cci_crh ON catalog_returns_history; 8 | CREATE CLUSTERED COLUMNSTORE INDEX cci_ssh ON store_sales_history; 9 | CREATE CLUSTERED COLUMNSTORE INDEX cci_srh ON store_returns_history; 10 | CREATE CLUSTERED COLUMNSTORE INDEX cci_ih ON inventory_history; 11 | 12 | 2) non-clustered B-tree indexes on sales and inventory tables 13 | CREATE INDEX csDate on catalog_sales (cs_sold_date_sk); 14 | CREATE INDEX ssDate on store_sales (ss_sold_date_sk); 15 | CREATE INDEX wsDate on web_sales (ws_sold_date_sk); 16 | CREATE INDEX invDate on inventory (inv_date_sk); 17 | 18 | 3) All non-history tables fact tables and dimension tables have clustered indexes on their primary key attributes; which were created as part of the create table statements itself. -------------------------------------------------------------------------------- /src/PLPgSQL/Scalar UDFs/proc62_totalCustLoss.sql: -------------------------------------------------------------------------------- 1 | create or replace function custTotalLoss(returnReason char(100)) 2 | returns refcursor 3 | AS $$ 4 | declare 5 | c3 refcursor := 'mycursor'; 6 | orderNo int; item int; 7 | reasonSk int; 8 | soldAmt decimal(7, 2); retCredit decimal(7, 2); 9 | totalCustLoss decimal(15, 0); 10 | c1 cursor is (select wr_order_number, wr_item_sk, wr_refunded_cash from web_returns where wr_reason_sk=1); 11 | c2 cursor is (select cr_order_number, cr_item_sk, cr_refunded_cash from catalog_returns where cr_reason_sk=1); 12 | 13 | begin 14 | totalCustLoss:=0; 15 | reasonSk := (select r_reason_sk from reason where r_reason_desc=returnReason); 16 | open c1; 17 | fetch c1 into orderNo, item, retCredit; 18 | while found loop 19 | soldAmt := (select ws_net_paid_inc_ship_tax from web_sales where ws_order_number = orderNo and ws_item_sk=item); 20 | totalCustLoss := totalCustLoss+ soldAmt - retCredit ; 21 | fetch c1 into orderNo, item, retCredit; 22 | end loop; 23 | close c1; 24 | 25 | open c2; 26 | fetch c2 into orderNo, item, retCredit; 27 | while found loop 28 | soldAmt := (select cs_net_paid_inc_ship_tax from catalog_sales where cs_order_number = orderNo and cs_item_sk=item); 29 | totalCustLoss := totalCustLoss+ soldAmt - retCredit ; 30 | fetch c2 into orderNo, item, retCredit; 31 | end loop; 32 | close c2; 33 | 34 | open c3 for 35 | select totalCustLoss; 36 | return c3; 37 | end; $$ 38 | language plpgsql -------------------------------------------------------------------------------- /src/PLPgSQL/Scalar UDFs/sudf_10_isListDistinct.sql: -------------------------------------------------------------------------------- 1 | -- Check if a given list of varchars is distinct. Called from sudf_14_sameManager 2 | 3 | CREATE OR REPLACE FUNCTION isListDistinct(list TEXT, delim CHAR) RETURNS BOOL AS 4 | $$ 5 | DECLARE 6 | part TEXT; 7 | pos INT; 8 | BEGIN 9 | list := LTRIM(RTRIM(list)) || delim; 10 | pos := STRPOS(list, delim); 11 | WHILE pos > 0 LOOP 12 | part := LTRIM(RTRIM(LEFT(list,pos))); 13 | list := SUBSTRING(list, pos+1, LENGTH(list)); 14 | IF STRPOS(list,part) <> 0 THEN 15 | RETURN FALSE; 16 | END IF; 17 | 18 | pos := STRPOS(list,delim); 19 | END LOOP; 20 | 21 | RETURN TRUE; 22 | END 23 | $$ LANGUAGE PLPGSQL; -------------------------------------------------------------------------------- /src/PLPgSQL/Scalar UDFs/sudf_11_genRandomChar.sql: -------------------------------------------------------------------------------- 1 | --Pick a random character from a given list of characters. This is called from stored procedure proc_24_CreateRandomString 2 | 3 | CREATE or REPLACE FUNCTION genRandomChar(chars varchar, rand float ) 4 | RETURNS CHAR 5 | language plpgsql 6 | as $$ 7 | declare 8 | rslt CHAR(1) := NULL; 9 | resultIndex INT := NULL; 10 | BEGIN 11 | IF chars IS NULL then 12 | rslt := NULL; 13 | ELSIF LENGTH(chars) = 0 then 14 | rslt := NULL; 15 | ELSE 16 | resultIndex := genRandomInt(1, LENGTH(chars), rand); 17 | rslt := SUBSTR(chars, resultIndex, 1); 18 | END IF; 19 | RETURN rslt; 20 | END; $$ -------------------------------------------------------------------------------- /src/PLPgSQL/Scalar UDFs/sudf_13_maxPurchaseChannel.sql: -------------------------------------------------------------------------------- 1 | create or replace function maxPurchaseChannel(ckey int, fromDateSk int, toDateSk int) 2 | returns varchar (50) 3 | language plpgsql 4 | as 5 | $$ 6 | declare 7 | numSalesFromStore int; 8 | numSalesFromCatalog int; 9 | numSalesFromWeb int; 10 | maxChannel varchar(50); 11 | begin 12 | select count(*) into numSalesFromStore 13 | from store_sales_history 14 | where ss_customer_sk = ckey and 15 | ss_sold_date_sk>=fromDateSk and 16 | ss_sold_date_sk<=toDateSk; 17 | 18 | select count(*) into numSalesFromCatalog 19 | from catalog_sales_history 20 | where cs_bill_customer_sk = ckey and 21 | cs_sold_date_sk>=fromDateSk and 22 | cs_sold_date_sk<=toDateSk; 23 | 24 | select count(*) into numSalesFromWeb 25 | from web_sales_history 26 | where ws_bill_customer_sk = ckey and 27 | ws_sold_date_sk>=fromDateSk and 28 | ws_sold_date_sk<=toDateSk; 29 | 30 | if(numSalesFromStore>numSalesFromCatalog)then 31 | maxChannel := 'Store'; 32 | if(numSalesfromWeb>numSalesFromStore)then 33 | maxChannel := 'Web'; 34 | end if; 35 | else 36 | maxChannel := 'Catalog'; 37 | if(numSalesfromWeb>numSalesFromCatalog)then 38 | maxChannel := 'Web'; 39 | end if; 40 | end if; 41 | 42 | return maxChannel; 43 | end; 44 | $$; 45 | 46 | select c_customer_sk, maxPurchaseChannel(c_customer_sk, 2000, 2020) as channel from customer -------------------------------------------------------------------------------- /src/PLPgSQL/Scalar UDFs/sudf_14_sameManager.sql: -------------------------------------------------------------------------------- 1 | --check if multiple large stores(>250 employees) are managed by the same person. 2 | 3 | CREATE OR REPLACE FUNCTION sameManagerForLargeStores() RETURNS BOOL AS 4 | $$ 5 | DECLARE 6 | manag TEXT; 7 | allManag TEXT; 8 | c1 TEXT; 9 | BEGIN 10 | allManag := ''; 11 | 12 | FOR c1 IN (SELECT s_manager FROM STORE where s_number_employees>250) LOOP 13 | allManag := allManag || c1 || ', '; 14 | END LOOP; 15 | 16 | RETURN NOT isListDistinct(allManag, ','); 17 | END 18 | $$ LANGUAGE PLPGSQL; -------------------------------------------------------------------------------- /src/PLPgSQL/Scalar UDFs/sudf_17_preferredChannel_wrtCount.sql: -------------------------------------------------------------------------------- 1 | --for all customers, find out the preferred channel wrt number of orders made. 2 | 3 | create or replace function preferredChannel_wrtCount(cust_key int) 4 | returns varchar(50) 5 | language plpgsql 6 | as 7 | $$ 8 | declare 9 | numWeb int; 10 | numStore int; 11 | numCat int; 12 | begin 13 | numWeb :=0; 14 | numStore :=0; 15 | numCat :=0; 16 | select count(*) into numWeb from web_sales_history where ws_bill_customer_sk=cust_key; 17 | select count(*) into numStore from store_sales_history where ss_customer_sk=cust_key; 18 | select count(*) into numCat from catalog_sales_history where cs_bill_customer_sk=cust_key; 19 | if(numWeb>=numStore and numWeb>=numCat) then 20 | return 'web'; 21 | end if; 22 | if(numStore>=numWeb and numStore>=numCat) then 23 | return 'store'; 24 | end if; 25 | if(numCat>=numStore and numCat>=numWeb) then 26 | return 'Catalog'; 27 | end if; 28 | return 'Logical error'; 29 | end; 30 | $$; 31 | 32 | --inovocation query 33 | select c_customer_sk, preferredChannel_wrtCount(c_customer_sk) from customer; -------------------------------------------------------------------------------- /src/PLPgSQL/Scalar UDFs/sudf_18_preferredChannel_wrtExpenditure.sql: -------------------------------------------------------------------------------- 1 | --for all customers, find out the preferred channel wrt money spent. 2 | create or replace function preferredChannel_wrtExpenditure(cust_key int) 3 | returns varchar(50) 4 | language plpgsql 5 | as 6 | $$ 7 | declare 8 | numWeb decimal; 9 | numStore decimal; 10 | numCat decimal; 11 | begin 12 | numWeb:=0; numStore:=0; numCat:=0; 13 | if exists (select * from web_sales_history where ws_bill_customer_sk=cust_key) then 14 | numWeb := (select sum(ws_net_paid_inc_ship_tax) from web_sales_history where ws_bill_customer_sk=cust_key); 15 | end if; 16 | if exists (select * from store_sales_history where ss_customer_sk=cust_key) then 17 | numStore := (select sum(ss_net_paid_inc_tax) from store_sales_history where ss_customer_sk=cust_key); 18 | end if; 19 | if exists (select * from catalog_sales_history where cs_bill_customer_sk=cust_key) then 20 | numCat := (select sum(cs_net_paid_inc_ship_tax) from catalog_sales_history where cs_bill_customer_sk=cust_key); 21 | end if; 22 | if(numWeb>=numStore and numWeb>=numCat) then 23 | return 'web'; 24 | end if; 25 | if(numStore>=numWeb and numStore>=numCat) then 26 | return 'store'; 27 | end if; 28 | if(numCat>=numStore and numCat>=numWeb) then 29 | return 'Catalog'; 30 | end if; 31 | return 'Logical error'; 32 | end; $$ 33 | 34 | --invocation Query 35 | select c_customer_sk, preferredChannel_wrtExpenditure(c_customer_sk) from customer; 36 | -------------------------------------------------------------------------------- /src/PLPgSQL/Scalar UDFs/sudf_1_totalLargePurchases.sql: -------------------------------------------------------------------------------- 1 | --Report the total catalog sales for customers from a given state who made purchases of 2 | -- more than a given amount for a given year and quarter. 3 | 4 | create or replace function totalLargePurchases(givenState char, amount decimal, yr int, qtr int) 5 | returns decimal 6 | language plpgsql 7 | as 8 | $$ 9 | declare 10 | largePurchase decimal; 11 | begin 12 | select sum(cs_net_paid_inc_ship_tax) into largePurchase 13 | from catalog_sales_history, customer, customer_address, date_dim 14 | where cs_bill_customer_sk = c_customer_sk and 15 | c_current_addr_sk = ca_address_sk and 16 | ca_state = givenState and 17 | cs_net_paid_inc_ship_tax >= amount and 18 | d_date_sk = cs_sold_date_sk and d_year = yr and d_qoy = qtr; 19 | return largePurchase; 20 | end; 21 | $$; 22 | 23 | --invocation query 24 | select ca_state, d_year, d_qoy, dbo.totalLargePurchases(ca_state, 1000, d_year, d_qoy) 25 | from customer_address, date_dim 26 | where d_year in (1998, 1999, 2000) and ca_state is not NULL 27 | group by ca_state, d_year, d_qoy 28 | order by ca_state, d_year, d_qoy; -------------------------------------------------------------------------------- /src/PLPgSQL/Scalar UDFs/sudf_20a_GetManufactSimple.sql: -------------------------------------------------------------------------------- 1 | create or replace function getManufact_simple(itm int) 2 | returns char(50) 3 | language plpgsql 4 | as 5 | $$ 6 | begin 7 | return (select i_manufact from item where i_item_sk = itm); 8 | end; $$ 9 | 10 | 11 | --complex calling query 12 | select maxsoldItem 13 | from 14 | (select ss_item_sk as maxSoldItem 15 | from 16 | (select ss_item_sk, sum(cnt) totalCnt 17 | from 18 | (select ss_item_sk, count(*) cnt from store_sales_history group by ss_item_sk 19 | union all 20 | select cs_item_sk, count(*) cnt from catalog_sales_history group by cs_item_sk 21 | union all 22 | select ws_item_sk, count(*) cnt from web_sales_history group by ws_item_sk )t1 23 | group by ss_item_sk)t2 24 | order by totalCnt desc 25 | limit 25000 26 | )t3 27 | where getManufact_simple(maxSoldItem) = 'oughtn st'; 28 | 29 | 30 | --Simple Calling Query 31 | select ws_item_sk 32 | from 33 | (select ws_item_sk, count(*) cnt from web_sales group by ws_item_sk order by cnt limit 25000)t1 34 | where getManufact_simple(ws_item_sk) = 'oughtn st'; -------------------------------------------------------------------------------- /src/PLPgSQL/Scalar UDFs/sudf_2_maxPromoChannel.sql: -------------------------------------------------------------------------------- 1 | create or replace function maxPromoChannel(year int) 2 | returns varchar 3 | language plpgsql 4 | as 5 | $$ 6 | declare 7 | begin 8 | return promoVsNoPromoItems(year); 9 | end; 10 | $$ 11 | 12 | select dbo.maxPromoChannel(2001); -------------------------------------------------------------------------------- /src/PLPgSQL/Scalar UDFs/sudf_3a_maxRetReasonWeb.sql: -------------------------------------------------------------------------------- 1 | --most frequent reason for returns on the web 2 | 3 | create or replace function maxReturnReasonWeb() 4 | returns char (100) 5 | language plpgsql 6 | as 7 | $$ 8 | declare 9 | reason_desc char(100); 10 | reason_id char(16); 11 | begin 12 | 13 | select dt1.r_reason_id, dt1.r_reason_desc 14 | into reason_id, reason_desc 15 | from 16 | (select r_reason_id, r_reason_desc, count(*) as cnt 17 | from web_returns_history, reason 18 | where wr_reason_sk = r_reason_sk 19 | group by r_reason_id, r_reason_desc) dt1 20 | where dt1.cnt = (select max(cnt) 21 | from (select r_reason_id, r_reason_desc, count(*) as cnt 22 | from web_returns_history, reason 23 | where wr_reason_sk = r_reason_sk 24 | group by r_reason_id, r_reason_desc)dt2 25 | ); 26 | return reason_desc; 27 | end; 28 | $$; 29 | 30 | --invocation query 31 | select maxReturnReasonWeb() as ans; -------------------------------------------------------------------------------- /src/PLPgSQL/Scalar UDFs/sudf_3b_maxRetReasonCat.sql: -------------------------------------------------------------------------------- 1 | --most frequent reason for returns on the catalog 2 | 3 | create or replace function maxReturnReasonCatalog() 4 | returns char(100) 5 | language plpgsql 6 | as 7 | $$ 8 | declare 9 | reason_desc char(100); 10 | reason_id char(16); 11 | begin 12 | 13 | select dt1.r_reason_id, dt1.r_reason_desc 14 | into reason_id, reason_desc 15 | from 16 | (select r_reason_id, r_reason_desc, count(*) as cnt 17 | from catalog_returns_history, reason 18 | where cr_reason_sk = r_reason_sk 19 | group by r_reason_id, r_reason_desc) dt1 20 | where dt1.cnt = (select max(cnt) 21 | from (select r_reason_id, r_reason_desc, count(*) as cnt 22 | from catalog_returns_history, reason 23 | where cr_reason_sk = r_reason_sk 24 | group by r_reason_id, r_reason_desc)dt2 25 | ); 26 | return reason_desc; 27 | end; 28 | $$; 29 | -------------------------------------------------------------------------------- /src/PLPgSQL/Scalar UDFs/sudf_3c_maxRetReasonStore.sql: -------------------------------------------------------------------------------- 1 | ----most frequent reason for returns through stores 2 | 3 | create or replace function maxReturnReasonStore() 4 | returns char(100) 5 | language plpgsql 6 | as 7 | $$ 8 | declare 9 | reason_desc char(100); 10 | reason_id char(16); 11 | begin 12 | 13 | select dt1.r_reason_id, dt1.r_reason_desc 14 | into reason_id, reason_desc 15 | from 16 | (select r_reason_id, r_reason_desc, count(*) as cnt 17 | from store_returns_history, reason 18 | where sr_reason_sk = r_reason_sk 19 | group by r_reason_id, r_reason_desc) dt1 20 | where dt1.cnt = (select max(cnt) 21 | from (select r_reason_id, r_reason_desc, count(*) as cnt 22 | from store_returns_history, reason 23 | where sr_reason_sk = r_reason_sk 24 | group by r_reason_id, r_reason_desc)dt2 25 | ); 26 | return reason_desc; 27 | end; 28 | $$; 29 | 30 | -------------------------------------------------------------------------------- /src/PLPgSQL/Scalar UDFs/sudf_4_genRandomInt.sql: -------------------------------------------------------------------------------- 1 | --Generate a random integer between given lower and upper bounds Called from sudf_11_genRandomChar 2 | 3 | CREATE or REPLACE FUNCTION genRandomInt 4 | ( 5 | lower INT, 6 | upper INT, 7 | rand FLOAT 8 | ) 9 | RETURNS INT 10 | language plpgsql 11 | as $$ 12 | declare 13 | result INT; 14 | range int; 15 | BEGIN 16 | range := upper - lower + 1; 17 | result := FLOOR(rand * range + lower); 18 | RETURN result; 19 | END; $$ 20 | 21 | -------------------------------------------------------------------------------- /src/PLPgSQL/Scalar UDFs/sudf_5_morEveRatio.sql: -------------------------------------------------------------------------------- 1 | --What is the ratio between the number of items sold over the internet in the morning (8 to 9am) to the number of 2 | --items sold in the evening (7 to 8pm) of customers with a specified number of dependents. 3 | 4 | create or replace function morningToEveRatio(dep int) 5 | returns float 6 | language plpgsql 7 | as 8 | $$ 9 | declare 10 | morningSale int; 11 | declare eveningSale int; 12 | declare ratio float; 13 | begin 14 | morningSale := (select count(*) 15 | from web_sales_history, time_dim, customer_demographics 16 | where ws_sold_time_sk = t_time_sk and ws_bill_customer_sk = cd_demo_sk 17 | and t_hour>=8 and t_hour<=9 18 | and cd_dep_count=dep); 19 | 20 | eveningSale := (select count(*) 21 | from web_sales_history, time_dim, customer_demographics 22 | where ws_sold_time_sk = t_time_sk and ws_bill_customer_sk = cd_demo_sk 23 | and t_hour>=19 and t_hour<=20 24 | and cd_dep_count=dep); 25 | 26 | ratio := cast (morningSale as float) / cast (eveningSale as float); 27 | return ratio; 28 | end; $$ 29 | 30 | --invocation query 31 | select t.depCount, morningToEveRatio(t.depCount) from 32 | (select distinct cd_dep_count as depCount from customer_demographics)t; -------------------------------------------------------------------------------- /src/PLPgSQL/Scalar UDFs/sudf_6_totalDiscount.sql: -------------------------------------------------------------------------------- 1 | --Compute the total discount on web sales of items from a given manufacturer for 2 | --sales whose discount exceeded 30% over the average discount of items from that manufacturer. 3 | 4 | create or replace function totalDiscount (manufacture_id int) 5 | returns decimal 6 | language plpgsql 7 | as 8 | $$ 9 | declare 10 | average decimal; 11 | addition decimal; 12 | begin 13 | select avg(ws_ext_discount_amt) into average from web_sales_history, item 14 | where ws_item_sk = i_item_sk and i_manufact_id = manufacture_id; 15 | 16 | select sum(ws_ext_discount_amt) into addition from web_sales_history, item 17 | where ws_item_sk = i_item_sk and i_manufact_id = manufacture_id and 18 | ws_ext_discount_amt>1.3*average; 19 | return addition; 20 | end; 21 | $$; 22 | 23 | select distinct i_manufact_id, totalDiscount(i_manufact_id) as totalDisc from item; -------------------------------------------------------------------------------- /src/PLPgSQL/Scalar UDFs/sudf_7_profitableManager.sql: -------------------------------------------------------------------------------- 1 | --were the stores run by this manager profitable in the given year? 2 | 3 | CREATE OR REPLACE FUNCTION profitableManager(manager VARCHAR(40), yr INT) 4 | RETURNS INT AS 5 | $$ 6 | DECLARE 7 | netProfit decimal(15,2); 8 | BEGIN 9 | netProfit := (SELECT SUM(ss_net_profit) 10 | FROM store, store_sales_history, date_dim 11 | WHERE ss_sold_date_sk = d_date_sk 12 | AND d_year = yr 13 | AND s_manager = manager 14 | AND s_store_sk = ss_store_sk); 15 | 16 | IF netProfit > 0 THEN 17 | RETURN 1; 18 | ELSE 19 | RETURN 0; 20 | END IF; 21 | END 22 | $$ LANGUAGE PLPGSQL; 23 | 24 | --invocation query 25 | select s_manager from store where dbo.profitableManager(s_manager, 2001)<=0; 26 | -------------------------------------------------------------------------------- /src/PLPgSQL/Scalar UDFs/sudf_8_maxRetClass.sql: -------------------------------------------------------------------------------- 1 | --Class of items that is returned the most on catalog in the curent cycle (non-history). 2 | 3 | CREATE OR REPLACE FUNCTION maxReturnClass() RETURNS CHAR (50) AS 4 | $$ 5 | DECLARE 6 | count INT8; 7 | class CHAR(50); 8 | maxClass CHAR(50); 9 | maxReturn INT8 := 0; 10 | c1 CURSOR FOR (SELECT i_class, COUNT(i_class) AS cnt 11 | FROM catalog_returns, item 12 | WHERE i_item_sk = cr_item_sk 13 | GROUP BY i_class 14 | ); 15 | BEGIN 16 | 17 | OPEN c1; 18 | FETCH c1 INTO class, count; 19 | 20 | WHILE found LOOP 21 | IF count > maxReturn THEN 22 | maxReturn := count; 23 | maxClass := class; 24 | END IF; 25 | FETCH c1 INTO class, count; 26 | END LOOP; 27 | 28 | RETURN maxClass; 29 | END 30 | $$ LANGUAGE PLPGSQL; -------------------------------------------------------------------------------- /src/PLPgSQL/Scalar UDFs/sudf_9a_correlation_wealthShipCost_Catalog.sql: -------------------------------------------------------------------------------- 1 | -- see if there is correlation betwen paying high shipping costs through catalog and 2 | --having a large number of high income inhabitants (at the state level)) 3 | 4 | create or replace function wealth_shipCostCorrelation_cat() 5 | returns varchar(40) 6 | language plpgsql 7 | as 8 | $$ 9 | declare 10 | numStates int; 11 | begin 12 | numStates := 0; 13 | 14 | numStates := (select count(*) from 15 | ( select ca_state from 16 | (select ca_state, sum(cs_ext_ship_cost) as sm 17 | from catalog_sales_history, customer_address 18 | where cs_bill_customer_sk = ca_address_sk and ca_state is not NULL 19 | group by ca_state 20 | order by sm desc 21 | limit 5)t1 22 | 23 | INTERSECT 24 | 25 | select ca_state from --states wth largest numeber high income people 26 | (select ca_state, count(*) as cnt 27 | from customer, household_demographics, customer_address 28 | where c_current_hdemo_sk = hd_demo_sk and c_current_addr_sk = ca_address_sk and hd_income_band_sk>=15 and ca_state is not NULL 29 | group by ca_state 30 | order by cnt desc 31 | limit 5)t2 32 | )t3 ); 33 | 34 | if(numStates>=4) then 35 | return 'hihgly correlated'; 36 | end if; 37 | if(numStates>=2 and numStates<=3) then 38 | return 'somewhat correlated'; 39 | end if; 40 | if(numStates>=0 and numStates<=1) then 41 | return 'no correlation'; 42 | end if; 43 | return 'error'; 44 | end; $$ 45 | 46 | select wealth_shipCostCorrelation_cat() -------------------------------------------------------------------------------- /src/PLPgSQL/Scalar UDFs/sudf_9b_correlation_wealthShipCost_web.sql: -------------------------------------------------------------------------------- 1 | -- see if there is correlation betwen paying high shpping costs through web and 2 | --having a large number of high income inhabitants (at the state level)) 3 | 4 | create or replace function wealth_shipCostCorrelation_web() 5 | returns varchar(40) 6 | language plpgsql 7 | as 8 | $$ 9 | declare 10 | numStates int; 11 | begin 12 | numStates := 0; 13 | 14 | numStates := (select count(*) from 15 | ( select ca_state from 16 | (select ca_state, sum(ws_ext_ship_cost) as sm 17 | from web_sales_history, customer_address 18 | where ws_bill_customer_sk = ca_address_sk and ca_state is not NULL 19 | group by ca_state 20 | order by sm desc 21 | limit 5)t1 22 | 23 | INTERSECT 24 | 25 | select ca_state from --states with largest number of high income people 26 | (select ca_state, count(*) as cnt 27 | from customer, household_demographics, customer_address 28 | where c_current_hdemo_sk = hd_demo_sk and c_current_addr_sk = ca_address_sk and hd_income_band_sk>=15 and ca_state is not NULL 29 | group by ca_state 30 | order by cnt desc 31 | limit 5)t2 32 | )t3 ); 33 | 34 | if(numStates>=4) then 35 | return 'highly correlated'; 36 | end if; 37 | if(numStates>=2 and numStates<=3) then 38 | return 'somewhat correlated'; 39 | end if; 40 | if(numStates>=0 and numStates<=1) then 41 | return 'no correlation'; 42 | end if; 43 | return 'error'; 44 | end; $$ 45 | 46 | 47 | 48 | -------------------------------------------------------------------------------- /src/PLPgSQL/Stored Procedures/proc10_remove_item.sql: -------------------------------------------------------------------------------- 1 | CREATE PROCEDURE removeItem (item_sk int) 2 | language plpgsql 3 | as $$ 4 | begin 5 | DELETE from item where i_item_sk = item_sk; 6 | END; $$ -------------------------------------------------------------------------------- /src/PLPgSQL/Stored Procedures/proc11_repeatedShoppers.sql: -------------------------------------------------------------------------------- 1 | --people who shopped in 5 diffrent months in a given year from store 2 | 3 | create or replace function repeatedShoppers (yr int) 4 | returns refcursor 5 | AS $$ 6 | declare 7 | c1 refcursor := 'mycursor'; 8 | begin 9 | open c1 for 10 | select ss_customer_sk, count(*) 11 | from 12 | (select distinct ss_customer_sk, d_moy 13 | from store_sales_history, date_dim 14 | where ss_sold_date_sk = d_date_sk 15 | and d_year = yr 16 | and ss_customer_sk is not NULL 17 | )t 18 | group by ss_customer_sk 19 | having count(*)>=5 20 | order by count(*) desc; 21 | 22 | return c1; 23 | end; $$ 24 | language plpgsql 25 | 26 | select repeatedShoppers(1998); 27 | fetch all from mycursor; 28 | -------------------------------------------------------------------------------- /src/PLPgSQL/Stored Procedures/proc12_returnReason_highlyEducated.sql: -------------------------------------------------------------------------------- 1 | create or replace function returnReason_highEducated() 2 | returns refcursor 3 | AS $$ 4 | declare 5 | c1 refcursor := 'mycursor'; 6 | begin 7 | open c1 for 8 | select r_reason_desc, count(*) as cnt 9 | from store_returns_history, customer_demographics, reason 10 | where sr_customer_sk = cd_demo_sk and sr_reason_sk = r_reason_sk and cd_education_status = 'Advanced Degree' 11 | group by r_reason_desc 12 | order by cnt desc; 13 | 14 | return c1; 15 | end; $$ 16 | language plpgsql 17 | 18 | select returnReason_highEducated(); 19 | fetch all from mycursor; -------------------------------------------------------------------------------- /src/PLPgSQL/Stored Procedures/proc13_returnReason_lessEducated.sql: -------------------------------------------------------------------------------- 1 | create or replace function returnReason_lessEducated() 2 | returns refcursor 3 | AS $$ 4 | declare 5 | c1 refcursor := 'mycursor'; 6 | begin 7 | open c1 for 8 | select r_reason_desc, count(*) as cnt 9 | from store_returns_history, customer_demographics, reason 10 | where sr_customer_sk = cd_demo_sk and sr_reason_sk = r_reason_sk and cd_education_status = 'Primary' 11 | group by r_reason_desc 12 | order by cnt desc; 13 | 14 | return c1; 15 | end; $$ 16 | language plpgsql 17 | 18 | select returnReason_lessEducated(); 19 | fetch all from mycursor; -------------------------------------------------------------------------------- /src/PLPgSQL/Stored Procedures/proc14_salePerBrandCatalog.sql: -------------------------------------------------------------------------------- 1 | --Report the total extended sales price per item brand of a specific manufacturer for all catalog sales in a specific month 2 | --of the year. 3 | CREATE or replace function salePerBrandCatalog (yr int, mnth int, manufacture int) 4 | returns refcursor 5 | AS $$ 6 | declare 7 | c1 refcursor := 'mycursor'; 8 | begin 9 | open c1 for 10 | select i_brand, sum(cs_ext_sales_price) as totalSale 11 | from catalog_sales_history, item, date_dim 12 | where i_item_sk = cs_item_sk 13 | and i_manufact_id = manufacture 14 | and cs_sold_date_sk = d_date_sk 15 | and d_year = yr 16 | and d_moy = mnth 17 | group by i_brand; 18 | 19 | return c1; 20 | END; $$ 21 | language plpgsql -------------------------------------------------------------------------------- /src/PLPgSQL/Stored Procedures/proc15_salePerBrandStore.sql: -------------------------------------------------------------------------------- 1 | --Report the total extended sales price per item brand of a specific manufacturer for all store sales in a specific month 2 | --of the year. 3 | CREATE or replace function salePerBrandStore (yr int, mnth int, manufacture int) 4 | returns refcursor 5 | AS $$ 6 | declare 7 | c1 refcursor := 'mycursor'; 8 | begin 9 | open c1 for 10 | select i_brand, sum(ss_ext_sales_price) as totalSale 11 | from store_sales_history, item, date_dim 12 | where i_item_sk = ss_item_sk 13 | and i_manufact_id = manufacture 14 | and ss_sold_date_sk = d_date_sk 15 | and d_year = yr 16 | and d_moy = mnth 17 | group by i_brand; 18 | 19 | return c1; 20 | END; $$ 21 | language plpgsql -------------------------------------------------------------------------------- /src/PLPgSQL/Stored Procedures/proc16_salePerBrandWeb.sql: -------------------------------------------------------------------------------- 1 | --Report the total extended sales price per item brand of a specific manufacturer for all web sales in a specific month 2 | --of the year. 3 | CREATE or replace function salePerBrandWeb (yr int, mnth int, manufacture int) 4 | returns refcursor 5 | AS $$ 6 | declare 7 | c1 refcursor := 'mycursor'; 8 | begin 9 | open c1 for 10 | select i_brand, sum(ws_ext_sales_price) as totalSale 11 | from web_sales_history, item, date_dim 12 | where i_item_sk = ws_item_sk 13 | and i_manufact_id = manufacture 14 | and ws_sold_date_sk = d_date_sk 15 | and d_year = yr 16 | and d_moy = mnth 17 | group by i_brand; 18 | 19 | return c1; 20 | END; $$ 21 | language plpgsql -------------------------------------------------------------------------------- /src/PLPgSQL/Stored Procedures/proc17_saleShoppers.sql: -------------------------------------------------------------------------------- 1 | --information on customers who purchased items from catalog that were on sale during a particular time 2 | CREATE or replace function saleShoppers() 3 | returns refcursor 4 | AS $$ 5 | declare 6 | c1 refcursor := 'mycursor'; 7 | begin 8 | open c1 for 9 | select cs_bill_customer_sk as customer_sk, 10 | c_first_name, c_last_name, c_email_address, c_birth_year, 11 | cs_item_sk, d1.d_date as sold_date, 12 | d2.d_date as promo_strt_date, d3.d_date as promo_end_date, 13 | cs_promo_sk 14 | from catalog_sales_history, promotion, date_dim d1, date_dim d2, date_dim d3, customer 15 | where p_promo_sk = cs_promo_sk 16 | and cs_sold_date_sk = d1.d_date_sk 17 | and p_start_date_sk = d2.d_date_sk 18 | and p_end_date_sk = d3.d_date_sk 19 | and d1.d_date>=d2.d_date 20 | and d1.d_date<=d3.d_date 21 | and cs_bill_customer_sk = c_customer_sk; 22 | 23 | return c1; 24 | 25 | END; $$ 26 | language plpgsql -------------------------------------------------------------------------------- /src/PLPgSQL/Stored Procedures/proc18_updateItemPrice.sql: -------------------------------------------------------------------------------- 1 | CREATE PROCEDURE updateItemPrice (itemSk int, newPrice decimal(7, 2)) 2 | language plpgsql 3 | as $$ 4 | declare 5 | BEGIN 6 | UPDATE item set i_current_price = newPrice 7 | where i_item_sk = itemSk 8 | and @newPrice < 3*i_wholesale_cost; 9 | END; $$ -------------------------------------------------------------------------------- /src/PLPgSQL/Stored Procedures/proc19_updateWebUrl.sql: -------------------------------------------------------------------------------- 1 | CREATE PROCEDURE updateWebURL(oldUrl varchar(100), newUrl varchar(100)) 2 | language plpgsql 3 | as $$ 4 | declare 5 | BEGIN 6 | 7 | UPDATE web_page 8 | set wp_url = newUrl 9 | where wp_url = oldUrl; 10 | END; $$ 11 | -------------------------------------------------------------------------------- /src/PLPgSQL/Stored Procedures/proc1_custDemoSaleInfo.sql: -------------------------------------------------------------------------------- 1 | --Calculate the average sales quantity, average sales price, average wholesale cost, total wholesale cost for store 2 | --sales of different customer types (based on marital status and gender) from the given state. 3 | 4 | CREATE or replace function customerDemographicSalesInfo (st char(2)) 5 | returns refcursor 6 | AS $$ 7 | declare 8 | c1 refcursor := 'mycursor'; 9 | BEGIN 10 | open c1 for 11 | select ca_state, cd_gender, cd_marital_status, avg(ss_quantity) as avg_qty, avg(ss_sales_price) avg_sale, 12 | avg(ss_ext_wholesale_cost) as avg_wholsesale, sum(ss_ext_wholesale_cost) as sum_wholesale 13 | from store_sales_history, customer_demographics, customer, customer_address 14 | where ss_cdemo_sk = cd_demo_sk 15 | and c_customer_sk = ss_customer_sk 16 | and c_current_cdemo_sk = ca_address_sk 17 | and ca_state = st 18 | group by ca_state, cd_gender, cd_marital_status ; 19 | 20 | return c1; 21 | END; $$ 22 | language plpgsql 23 | 24 | --invocation 25 | BEGIN; 26 | SELECT customerDemographicSalesInfo('IL'); 27 | FETCH ALL from mycursor; 28 | COMMIT; -------------------------------------------------------------------------------- /src/PLPgSQL/Stored Procedures/proc20_warehouse_addressGet.sql: -------------------------------------------------------------------------------- 1 | CREATE function warehouseAddress_Get (warehouseId char(16)) 2 | returns refcursor 3 | AS $$ 4 | declare 5 | c1 refcursor := 'mycursor'; 6 | begin 7 | open c1 for 8 | select w_warehouse_name, w_street_number, w_street_name, w_suite_number, w_city, w_county, w_state, w_zip, w_country 9 | FROM warehouse 10 | where w_warehouse_id = warehouseId; 11 | 12 | return c1; 13 | END; $$ 14 | language plpgsql -------------------------------------------------------------------------------- /src/PLPgSQL/Stored Procedures/proc21_activatePromoCat.sql: -------------------------------------------------------------------------------- 1 | create or replace procedure activatePromoCat() 2 | language plpgsql 3 | as $$ 4 | declare 5 | promo_sk int; 6 | c1 cursor for (select promo_sk from bestPromosCatalog()); 7 | begin 8 | open c1; 9 | fetch c1 into promo_sk; 10 | while found LOOP 11 | update promotion set p_end_date_sk = 10000000, p_discount_active='Y' 12 | where p_promo_sk = @promo_sk; 13 | 14 | fetch c1 into promo_sk; 15 | end LOOP; 16 | end; $$ 17 | -------------------------------------------------------------------------------- /src/PLPgSQL/Stored Procedures/proc22_activatePromoStore.sql: -------------------------------------------------------------------------------- 1 | create or replace procedure activatePromoStore() 2 | language plpgsql 3 | as $$ 4 | declare 5 | promo_sk int; 6 | c1 cursor for (select promo_sk from bestPromoStore()); 7 | begin 8 | open c1; 9 | fetch c1 into promo_sk; 10 | while found LOOP 11 | update promotion set p_end_date_sk = 10000000, p_discount_active='Y' 12 | where p_promo_sk = @promo_sk; 13 | 14 | fetch c1 into promo_sk; 15 | end LOOP; 16 | end; $$ -------------------------------------------------------------------------------- /src/PLPgSQL/Stored Procedures/proc23_activatePromoWeb.sql: -------------------------------------------------------------------------------- 1 | create or replace procedure activatePromoWeb() 2 | language plpgsql 3 | as $$ 4 | declare 5 | promo_sk int; 6 | c1 cursor for (select promo_sk from bestPromosWeb()); 7 | begin 8 | open c1; 9 | fetch c1 into promo_sk; 10 | while found LOOP 11 | update promotion set p_end_date_sk = 10000000, p_discount_active='Y' 12 | where p_promo_sk = @promo_sk; 13 | 14 | fetch c1 into promo_sk; 15 | end LOOP; 16 | end; $$ 17 | -------------------------------------------------------------------------------- /src/PLPgSQL/Stored Procedures/proc24_CreateRandmString.sql: -------------------------------------------------------------------------------- 1 | CREATE or replace PROCEDURE CreateRandomString (randomString INOUT VARCHAR(16)) 2 | language plpgsql 3 | AS $$ 4 | declare 5 | stringLength INT =16; 6 | chars VARCHAR(200); 7 | begin 8 | chars:= 'ABCDEFGHIJKLMNOPQRSTUVWXYZ'; 9 | randomString := ''; 10 | WHILE LENGTH(randomString) < stringLength loop 11 | randomString := randomString || genRandomChar(chars, random()); 12 | END LOOP; 13 | END; $$ 14 | 15 | --ivocation query 16 | call CreateRandomString('') 17 | 18 | 19 | 20 | -------------------------------------------------------------------------------- /src/PLPgSQL/Stored Procedures/proc25_delCatPage.sql: -------------------------------------------------------------------------------- 1 | create or replace procedure deleteCatalogPage( delContent varchar(20), updateContent varchar(20), updateDept varchar(40)) 2 | language plpgsql 3 | as $$ 4 | begin 5 | if( delContent!='') then 6 | delete from catalog_page where cp_description like '%' || delContent || '%'; 7 | end if; 8 | 9 | if( updateContent!='') then 10 | update catalog_page set cp_department = updateDept where cp_description like '%' || updateDept || '%'; 11 | end if; 12 | end; $$ 13 | 14 | --execution query 15 | call deleteCatalogPage ('weapon', 'patient', 'Medical') 16 | go 17 | -------------------------------------------------------------------------------- /src/PLPgSQL/Stored Procedures/proc27_getStoreByManager.sql: -------------------------------------------------------------------------------- 1 | create or replace function getStoreByManager(manager varchar(40)) 2 | returns refcursor 3 | AS $$ 4 | declare 5 | c1 refcursor := 'mycursor'; 6 | begin 7 | if not exists (select * from store where s_manager= manager) then 8 | raise exception 'No stores operated by this manager'; 9 | 10 | else 11 | open c1 for 12 | select s_street_number, s_street_name, s_street_type, s_suite_number, s_city, s_county, s_state,s_zip, s_country 13 | from store 14 | where s_manager = manager; 15 | end if; 16 | 17 | return c1; 18 | end; $$ 19 | language plpgsql -------------------------------------------------------------------------------- /src/PLPgSQL/Stored Procedures/proc28_insertCallCenter.sql: -------------------------------------------------------------------------------- 1 | CREATE PROCEDURE InsertCallCenter ( strt_date date, end_date date, cc_closed_date int, open_date int , cc_name varchar(50), 2 | sk int, id char(16), class varchar(50), numEmpl int, size int, hrs char(20), 3 | manager varchar(40), mkt_id int, mkt_cls char(50), mkt_desc varchar(100), 4 | Mktmanager varchar(40), div int, divName varchar(50), company int, company_name char(50), 5 | st_num char(10), stName varchar(60), stType char(15), cc_suite char(10), 6 | city varchar(60), county varchar(30), stat char(2), zip char(10), 7 | country varchar(20), offs decimal(5,2), taxPercent decimal(5,2)) 8 | language plpgsql 9 | as $$ 10 | BEGIN 11 | if not exists (select * from call_center where cc_call_center_sk = sk) then 12 | insert into call_center values ( strt_date, end_date, cc_closed_date, open_date, cc_name, sk, id, class, numEmpl, size, hrs, 13 | manager, mkt_id, mkt_cls, mkt_desc, Mktmanager, div, divName, company, 14 | company_name, st_num, stName, stType, cc_suite, cit, county, stat, zip, country, 15 | offs, taxPercent); 16 | end if; 17 | END; $$ -------------------------------------------------------------------------------- /src/PLPgSQL/Stored Procedures/proc29_insertNewShipCarrier.sql: -------------------------------------------------------------------------------- 1 | create or replace procedure newShippingCarrier(typ char(30), code char(10), nam char(20), 2 | contract char(20)) 3 | language plpgsql 4 | as $$ 5 | declare 6 | randomString varchar(16); 7 | sk int; 8 | ide char(16); 9 | begin 10 | sk := (select max(sm_ship_mode_sk)+1 from ship_mode ); 11 | randomString:=''; 12 | call CreateRandomString (randomString); 13 | ide := randomString; 14 | 15 | insert into ship_mode (sm_ship_mode_sk, sm_ship_mode_id, sm_type, sm_code, sm_carrier, sm_contract) 16 | values (sk, ide, typ, code, nam, contract); 17 | 18 | end; $$ 19 | 20 | --calling query 21 | call newShippingCarrier ('FORTNIGHT', 'SEA', 'SHIPCo', '83hdjk0hf8j') -------------------------------------------------------------------------------- /src/PLPgSQL/Stored Procedures/proc2_excessReturn_web.sql: -------------------------------------------------------------------------------- 1 | --Calculate the average sales quantity, average sales price, average wholesale cost, total wholesale cost for store 2 | --sales of different customer types (based on marital status and gender) from the given state. 3 | CREATE or replace function excessReturns_web() 4 | returns refcursor 5 | AS $$ 6 | declare 7 | c1 refcursor := 'mycursor'; 8 | BEGIN 9 | open c1 for 10 | WITH ReturnTable 11 | AS (SELECT wr_returning_customer_sk, 12 | ca_state, 13 | Sum(wr_return_amt) as returnAmt 14 | FROM web_returns_history, 15 | customer_address, 16 | date_dim 17 | WHERE wr_returned_date_sk = d_date_sk 18 | and wr_returning_addr_sk = ca_address_sk 19 | AND d_year = 2001 20 | GROUP BY wr_returning_customer_sk, 21 | ca_state) 22 | SELECT c_customer_id, c_salutation, c_first_name, c_last_name, c_email_address, c_birth_year, c_birth_country 23 | FROM ReturnTable tr1, 24 | customer_address ca1, 25 | customer 26 | WHERE tr1.returnAmt > (SELECT Avg(returnAmt) * 1.2 27 | FROM ReturnTable tr2 28 | WHERE tr1.ca_state = tr2.ca_state) 29 | AND ca_address_sk = c_current_addr_sk 30 | AND tr1.wr_returning_customer_sk = c_customer_sk 31 | AND ca1.ca_state = 'TX' ; 32 | return c1; 33 | END; $$ 34 | language plpgsql 35 | 36 | BEGIN; 37 | SELECT excessReturns_web(); 38 | FETCH ALL from mycursor; 39 | COMMIT; -------------------------------------------------------------------------------- /src/PLPgSQL/Stored Procedures/proc30_lossByEdcated-Risky.sql: -------------------------------------------------------------------------------- 1 | create or replace function lossByEducated_risky() 2 | returns refcursor 3 | AS $$ 4 | declare 5 | c1 refcursor := 'mycursor'; 6 | web_loss decimal(15,2); 7 | cat_loss decimal(15,2); 8 | total_loss decimal(15,2); 9 | begin 10 | select sum(ws_net_profit) into web_loss 11 | from web_sales_history 12 | where ws_bill_cdemo_sk in 13 | (select cd_demo_sk from customer_demographics where cd_gender='M' and cd_education_status = 'Advanced Degree' 14 | and cd_dep_count>0 and cd_credit_rating = 'High Risk') 15 | and ws_net_profit<0; 16 | 17 | select sum(cs_net_profit) into cat_loss 18 | from catalog_sales_history 19 | where cs_bill_cdemo_sk in 20 | (select cd_demo_sk from customer_demographics where cd_gender='M' and cd_education_status = 'Advanced Degree' 21 | and cd_dep_count>0 and cd_credit_rating = 'High Risk') 22 | and cs_net_profit<0; 23 | 24 | open c1 for 25 | select web_loss + cat_loss into total_loss; 26 | 27 | return c1; 28 | end; $$ 29 | language plpgsql -------------------------------------------------------------------------------- /src/PLPgSQL/Stored Procedures/proc31_maxSaleElectronicsMonth.sql: -------------------------------------------------------------------------------- 1 | --which months registered the highest sale of electronics for 3 year period startig at the given year. 2 | 3 | create or replace function maxSaleElectronicsMonth(yr int) 4 | returns refcursor 5 | AS $$ 6 | declare 7 | c1 refcursor := 'mycursor'; 8 | month1 int; month2 int; month3 int; 9 | begin 10 | month1 := (select d_moy 11 | from store_sales_history, item, date_dim 12 | where ss_item_sk = i_item_sk and ss_sold_date_sk=d_date_sk and d_year = yr and i_category='Electronics' 13 | group by d_moy 14 | order by count(*) desc 15 | limit 1); 16 | 17 | month2 := (select d_moy 18 | from store_sales_history, item, date_dim 19 | where ss_item_sk = i_item_sk and ss_sold_date_sk=d_date_sk and d_year = yr+1 and i_category='Electronics' 20 | group by d_moy 21 | order by count(*) desc 22 | limit 1); 23 | 24 | month3 := (select d_moy 25 | from store_sales_history, item, date_dim 26 | where ss_item_sk = i_item_sk and ss_sold_date_sk=d_date_sk and d_year = yr+2 and i_category='Electronics' 27 | group by d_moy 28 | order by count(*) desc 29 | limit 1); 30 | 31 | open c1 for 32 | select month1 , month2 , month3; 33 | 34 | return c1; 35 | end; $$ 36 | language plpgsql -------------------------------------------------------------------------------- /src/PLPgSQL/Stored Procedures/proc32_maxSaleJewelryMonth.sql: -------------------------------------------------------------------------------- 1 | --which months registered the highest sale of jewelry for 3 year period startig at the given year. 2 | 3 | create or replace function maxSaleJewelryMonth(yr int) 4 | returns refcursor 5 | AS $$ 6 | declare 7 | c1 refcursor := 'mycursor'; 8 | month1 int; month2 int; month3 int; 9 | begin 10 | month1 := (select d_moy 11 | from store_sales_history, item, date_dim 12 | where ss_item_sk = i_item_sk and ss_sold_date_sk=d_date_sk and d_year = yr and i_category='jewelry' 13 | group by d_moy 14 | order by count(*) desc 15 | limit 1); 16 | 17 | month2 := (select d_moy 18 | from store_sales_history, item, date_dim 19 | where ss_item_sk = i_item_sk and ss_sold_date_sk=d_date_sk and d_year = yr+1 and i_category='jewelry' 20 | group by d_moy 21 | order by count(*) desc 22 | limit 1); 23 | 24 | month3 := (select d_moy 25 | from store_sales_history, item, date_dim 26 | where ss_item_sk = i_item_sk and ss_sold_date_sk=d_date_sk and d_year = yr+2 and i_category='jewelry' 27 | group by d_moy 28 | order by count(*) desc 29 | limit 1); 30 | 31 | open c1 for 32 | select month1, month2, month3; 33 | 34 | return c1; 35 | end; $$ 36 | language plpgsql 37 | -------------------------------------------------------------------------------- /src/PLPgSQL/Stored Procedures/proc33_newCatalogPage.sql: -------------------------------------------------------------------------------- 1 | create or replace procedure newCatalogPage( strtDate int, endDate int, dept varchar(50), catNumber int, 2 | pgNum int, dsc varchar(100), typevarchar varchar(100)) 3 | language plpgsql 4 | as $$ 5 | declare 6 | randomString varchar(16); 7 | sk int; 8 | ide char(16); 9 | begin 10 | sk := (select max(cp_catalog_page_sk)+1 from catalog_page); 11 | randomString :=''; 12 | call CreateRandomString (randomString); 13 | ide := randomString; 14 | insert into catalog_page (cp_catalog_page_sk, cp_catalog_page_id, cp_start_date_sk, cp_end_date_sk, 15 | cp_department, cp_catalog_number, cp_catalog_page_number, cp_description, cp_type) 16 | values ( sk, ide, strtDate, endDate, dept, catNumber, pgNum, dsc, typevarchar); 17 | end; 18 | $$ -------------------------------------------------------------------------------- /src/PLPgSQL/Stored Procedures/proc34_newPromotion.sql: -------------------------------------------------------------------------------- 1 | create procedure new_promotion( item_sk int, start_date int, end_date int, cst decimal(15, 2)) 2 | language plpgsql 3 | as $$ 4 | declare 5 | newSk int; maxSk int; 6 | begin 7 | maxSk := (select max(p_promo_sk) from promotion); 8 | newSk := maxSk+1; 9 | 10 | insert into promotion(p_promo_sk, p_start_date_sk, p_end_date_sk, p_item_sk, p_cost, p_discount_active) 11 | values ( newSk, start_date, end_date, item_sk, cst, 'Y'); 12 | end; $$ -------------------------------------------------------------------------------- /src/PLPgSQL/Stored Procedures/proc35_newStore.sql: -------------------------------------------------------------------------------- 1 | create procedure newStore( store_sk int, manager varchar(40)) 2 | language plpgsql 3 | as $$ 4 | begin 5 | if not exists (select * from store where s_store_sk= store_sk) then 6 | insert into store (s_store_sk, s_store_id, s_manager) values ( store_sk, DEFAULT, manager); 7 | else 8 | update store set s_manager = manager where s_store_sk = store_sk; 9 | end if; 10 | end; $$ -------------------------------------------------------------------------------- /src/PLPgSQL/Stored Procedures/proc36_newWarehouse.sql: -------------------------------------------------------------------------------- 1 | --add a new warehouse to the database: 2 | create or replace procedure newWarehouse( nm varchar(20), sqFt int, streetNo char(10), stName varchar(60), 3 | suite char(10), city varchar(60), county varchar(30), st char(2), 4 | zip char(10), country varchar(20)) 5 | language plpgsql 6 | as $$ 7 | declare 8 | randomString varchar(16); 9 | sk int; 10 | ide char(16); 11 | begin 12 | sk := (select max(w_warehouse_sk)+1 from warehouse ); 13 | 14 | call CreateRandomString (randomString); 15 | ide := randomString; 16 | insert into warehouse (w_warehouse_sk, w_warehouse_id, w_warehouse_name, w_warehouse_sq_ft, w_street_number, 17 | w_street_name, w_suite_number, w_city, w_county, w_state, w_zip, w_country) 18 | values ( sk, ide, nm, sqFt, streetNo, stName, suite, city, county, st, zip, country); 19 | 20 | end; $$ -------------------------------------------------------------------------------- /src/PLPgSQL/Stored Procedures/proc37_procesStoreReturn.sql: -------------------------------------------------------------------------------- 1 | --new return request 2 | 3 | create procedure processReturn_store 4 | (item_sk int, cust_sk int, reason_sk int, ticketNum int, returnQty int, returnReason char(100)) 5 | language plpgsql 6 | as $$ 7 | declare 8 | curDate date; 9 | dateSk int; 10 | begin 11 | curdate:=GETDATE(); 12 | dateSk := (select d_date_sk from date_dim where d_date = curDate); 13 | insert into store_returns (sr_returned_date_sk, sr_item_sk, sr_customer_sk, sr_reason_sk, sr_ticket_number, sr_return_quantity) 14 | values (dateSk, item_sk, cust_sk, reason_sk, ticketNum, returnQty); 15 | if exists (select * from reason where r_reason_sk=reason_sk) then 16 | return; 17 | else 18 | insert into reason (r_reason_sk, r_reason_desc) values (reason_sk, returnReason); 19 | end if; 20 | end; $$ 21 | -------------------------------------------------------------------------------- /src/PLPgSQL/Stored Procedures/proc3_excessReturnCustInfo.sql: -------------------------------------------------------------------------------- 1 | CREATE or replace function getExcessReturnCustInfo() 2 | returns refcursor 3 | AS $$ 4 | declare 5 | c1 refcursor := 'mycursor'; 6 | BEGIN 7 | open c1 for 8 | WITH totalReturn 9 | AS (SELECT sr_customer_sk, 10 | sr_store_sk, 11 | Sum(sr_return_amt) as returnAmt 12 | FROM store_returns_history, 13 | date_dim 14 | WHERE sr_returned_date_sk = d_date_sk 15 | AND d_year = 2001 16 | GROUP BY sr_customer_sk, 17 | sr_store_sk) 18 | SELECT distinct c_customer_id, c_email_address, cd_gender, cd_credit_rating 19 | FROM totalReturn tr1, 20 | store, 21 | customer, 22 | customer_demographics 23 | WHERE tr1.returnAmt > (SELECT Avg(returnAmt) * 1.2 24 | FROM totalReturn tr2 25 | WHERE tr1.sr_store_sk = tr2.sr_store_sk) 26 | AND s_store_sk = tr1.sr_store_sk 27 | AND tr1.sr_customer_sk = c_customer_sk 28 | AND c_current_cdemo_sk = cd_demo_sk; 29 | 30 | return c1; 31 | end; $$ 32 | language plpgsql 33 | 34 | 35 | select getExcessReturnCustInfo(); 36 | fetch all from mycursor; 37 | -------------------------------------------------------------------------------- /src/PLPgSQL/Stored Procedures/proc44_cusWithIncomeInRange.sql: -------------------------------------------------------------------------------- 1 | --List all customers living in a specified city, in a given income band 2 | create or replace procedure cusWithIncomeInRange(city varchar(60), givenIb int) 3 | language plpgsql 4 | as $$ 5 | declare 6 | cust int; ib int; hhd int; 7 | c1 cursor is (select c_customer_sk from customer, customer_address 8 | where c_current_addr_sk=ca_address_sk and ca_city = city); 9 | begin 10 | open c1; 11 | fetch c1 into cust; 12 | while found loop 13 | hhd := (select c_current_hdemo_sk from customer where c_customer_sk = cust); 14 | ib := (select hd_income_band_sk from household_demographics where hd_demo_sk=hhd); 15 | if(ib = givenIb) then 16 | raise notice '%', cust; 17 | end if; 18 | fetch c1 into cust; 19 | end loop; 20 | end; $$ 21 | 22 | --execution query 23 | call cusWithIncomeInRange ('Hopewell', 2) -------------------------------------------------------------------------------- /src/PLPgSQL/Stored Procedures/proc45_moreOnlineThanStore.sql: -------------------------------------------------------------------------------- 1 | -- Customers who spend more money online than in stores 2 | 3 | create or replace procedure moreOnlineThanStore() 4 | language plpgsql 5 | as $$ 6 | declare 7 | preferredChannel varchar(50); 8 | cust int; 9 | c1 cursor is (select c_customer_sk from customer); 10 | begin 11 | open c1; 12 | fetch c1 into cust; 13 | while found loop 14 | preferredChannel := (select preferredChannel_wrtExpenditure(cust)); 15 | if(preferredChannel='catalog' or preferredChannel='web') then 16 | raise notice '%', cust; 17 | end if; 18 | fetch c1 into cust; 19 | end loop; 20 | end; $$ -------------------------------------------------------------------------------- /src/PLPgSQL/Stored Procedures/proc46_processReturn.sql: -------------------------------------------------------------------------------- 1 | --new return request 2 | 3 | create or replace procedure processReturn 4 | (channel char(1), item_sk int, cust_sk int, reason_sk int, orderNum int, returnQty int, returnReason char(100), 5 | retAmt decimal(7, 2), refundAmt decimal(7, 2)) 6 | language plpgsql 7 | as $$ 8 | declare 9 | curDate date; 10 | dateSk int; cnt int; 11 | randomString VARCHAR(16); 12 | reason_id varchar(16); 13 | begin 14 | curDate:=GETDATE(); 15 | dateSk := (select d_date_sk from date_dim where d_date = curDate); 16 | if(channel='c') then 17 | insert into catalog_returns (cr_returned_date_sk, cr_item_sk, cr_refunded_customer_sk, cr_reason_sk, 18 | cr_order_number, cr_return_quantity, cr_return_amt_inc_tax, cr_refunded_cash) 19 | values (dateSk, item_sk, cust_sk, reason_sk, orderNum, returnQty, retAmt, refundAmt); 20 | end if; 21 | if(channel='w') then 22 | insert into web_returns (wr_returned_date_sk, wr_item_sk, wr_refunded_customer_sk, wr_reason_sk, 23 | wr_order_number, wr_return_quantity, wr_return_amt_inc_tax, wr_refunded_cash) 24 | values (dateSk, item_sk, cust_sk, reason_sk, orderNum, returnQty , retAmt, refundAmt); 25 | end if; 26 | select count(*) into cnt from reason where r_reason_sk=reason_sk; 27 | if(cnt!=0) then 28 | return; 29 | else 30 | randomString := ''; 31 | call CreateRandomString (randomString); 32 | reason_id := randomString; 33 | insert into reason (r_reason_sk, r_reason_id, r_reason_desc) values (reason_sk, reason_id, returnReason); 34 | end if; 35 | end; $$ -------------------------------------------------------------------------------- /src/PLPgSQL/Stored Procedures/proc4_getCustomerInfo.sql: -------------------------------------------------------------------------------- 1 | create or replace function getCustomerInfo(custKey int) 2 | returns refcursor 3 | AS $$ 4 | declare 5 | c1 refcursor := 'mycursor'; 6 | BEGIN 7 | open c1 for 8 | select c_salutation, c_first_name, c_last_name, c_birth_year, c_email_address, 9 | ca_street_number, ca_street_name, ca_suite_number, ca_city, ca_county, ca_country 10 | from customer, customer_address 11 | where c_current_addr_sk = ca_address_sk 12 | and c_customer_sk = custKey; 13 | 14 | return c1; 15 | end; $$ 16 | language plpgsql 17 | 18 | 19 | select getCustomerInfo(1); 20 | fetch all from mycursor; 21 | -------------------------------------------------------------------------------- /src/PLPgSQL/Stored Procedures/proc52_catalogOrderCancellation.sql: -------------------------------------------------------------------------------- 1 | --process cancellation of an order from catalog and record reason in the reason table. 2 | 3 | create or replace procedure catalogOrderCancellation (item_sk int, orderNo int, reasonId int) 4 | language plpgsql 5 | as $$ 6 | declare 7 | shipDate date; curDate date; 8 | dateDiff int; reasonSk int; 9 | ide VARCHAR(16); 10 | begin 11 | if not exists (select * from catalog_sales where cs_item_sk=item_sk and cs_order_number=orderNo) then 12 | raise exception 'invalid order'; 13 | return; 14 | end if; 15 | curDate := CURRENT_DATE; 16 | shipDate := (select d_date from catalog_sales, date_dim 17 | where cs_ship_date_sk=d_date_sk and cs_item_sk=item_sk and cs_order_number=orderNo); 18 | dateDiff := DATE_PART('day', shipDate)-DATE_PART('day', curDate); 19 | if(dateDiff<=0) then 20 | raise exception 'item already shippTry returning later.'; 21 | return; 22 | else 23 | delete from catalog_sales where cs_item_sk=item_sk and cs_order_number=orderNo; 24 | if exists (select * from reason where r_reason_sk=reasonId) then 25 | return; 26 | else 27 | reasonSk := (select max(r_reason_sk)+1 from reason); 28 | call CreateRandomString (ide); 29 | insert into reason (r_reason_sk, r_reason_id) values (reasonSk, ide); 30 | end if; 31 | end if; 32 | end; $$ 33 | 34 | -------------------------------------------------------------------------------- /src/PLPgSQL/Stored Procedures/proc57_webOrderCancellation.sql: -------------------------------------------------------------------------------- 1 | --process cancellation of an order fromm web and record reason in the reason table. 2 | 3 | create or replace procedure webOrderCancellation (item_sk int, orderNo int, reasonId int) 4 | language plpgsql 5 | as $$ 6 | declare 7 | shipDate date; curDate date; 8 | dateDiff int; reasonSk int; 9 | ide VARCHAR(16); 10 | begin 11 | if not exists (select * from web_sales where ws_item_sk=item_sk and ws_order_number=orderNo) then 12 | raise exception 'invalid order'; 13 | return; 14 | end if; 15 | curDate := CURRENT_DATE; 16 | shipDate := (select d_date from web_sales, date_dim 17 | where ws_ship_date_sk=d_date_sk and ws_item_sk=item_sk and ws_order_number=orderNo); 18 | dateDiff := DATE_PART('day', shipDate)-DATE_PART('day', curDate); 19 | if(dateDiff<=0) then 20 | raise exception 'item already shipped. Try returning later.'; 21 | return; 22 | else 23 | delete from web_sales where ws_item_sk=item_sk and ws_order_number=orderNo; 24 | if exists (select * from reason where r_reason_sk=reasonId) then 25 | return; 26 | else 27 | reasonSk := (select max(r_reason_sk)+1 from reason); 28 | call CreateRandomString (ide); 29 | insert into reason (r_reason_sk, r_reason_id) values (reasonSk, ide); 30 | end if; 31 | end if; 32 | end; $$ -------------------------------------------------------------------------------- /src/PLPgSQL/Stored Procedures/proc5_getImmigrantCust.sql: -------------------------------------------------------------------------------- 1 | create or replace function getImmigrantCustomers() 2 | returns refcursor 3 | AS $$ 4 | declare 5 | c1 refcursor := 'mycursor'; 6 | begin 7 | open c1 for 8 | select c_customer_sk, c_birth_country, ca_state as currentState, cd_gender, cd_marital_status, 9 | cd_education_status, ib_lower_bound, ib_upper_bound, 10 | cd_credit_rating, cd_dep_count 11 | from customer, customer_address, household_demographics, income_band, customer_demographics 12 | where c_current_addr_sk = ca_address_sk 13 | and c_birth_country != ca_country 14 | and c_current_hdemo_sk=hd_demo_sk 15 | and hd_income_band_sk = ib_income_band_sk 16 | and cd_demo_sk = c_current_cdemo_sk 17 | and c_customer_sk is not NULL; 18 | return c1; 19 | end; $$ 20 | language plpgsql 21 | 22 | select getImmigrantCustomers(); 23 | fetch all from mycursor; -------------------------------------------------------------------------------- /src/PLPgSQL/Stored Procedures/proc6_getNativeCust.sql: -------------------------------------------------------------------------------- 1 | create or replace function getNativeCustomers() 2 | returns refcursor 3 | AS $$ 4 | declare 5 | c1 refcursor := 'mycursor'; 6 | begin 7 | open c1 for 8 | select c_customer_sk, ca_state, cd_gender, cd_marital_status, 9 | cd_education_status, ib_lower_bound, ib_upper_bound, 10 | cd_credit_rating, cd_dep_count 11 | from customer, customer_address, household_demographics, income_band, customer_demographics 12 | where c_current_addr_sk = ca_address_sk 13 | and c_birth_country=ca_country 14 | and c_current_hdemo_sk=hd_demo_sk 15 | and hd_income_band_sk = ib_income_band_sk 16 | and cd_demo_sk = c_current_cdemo_sk 17 | and c_customer_sk is not NULL; 18 | return c1; 19 | end; $$ 20 | language plpgsql 21 | 22 | 23 | select getNativeCustomers(); 24 | fetch all from mycursor; -------------------------------------------------------------------------------- /src/PLPgSQL/Stored Procedures/proc7_lowIncomeCustWithHighPurchase.sql: -------------------------------------------------------------------------------- 1 | CREATE or replace function lowIncomeCustomerWithHighPurchaseAmount(amount decimal(7, 2)) 2 | returns refcursor 3 | AS $$ 4 | declare 5 | c1 refcursor := 'mycursor'; 6 | begin 7 | open c1 for 8 | select distinct ss_customer_sk, ib_income_band_sk 9 | from store_sales_history, household_demographics, income_band 10 | where ss_hdemo_sk = hd_demo_sk 11 | and hd_income_band_sk = ib_income_band_sk 12 | and ss_net_paid_inc_tax>amount 13 | and ib_income_band_sk<=4; 14 | return c1; 15 | END; $$ 16 | language plpgsql 17 | 18 | select lowIncomeCustomerWithHighPurchaseAmount(1000); 19 | fetch all from mycursor; 20 | -------------------------------------------------------------------------------- /src/PLPgSQL/Stored Procedures/proc9_popularWP.sql: -------------------------------------------------------------------------------- 1 | --how may people shopped from a web_page 2 | create or replace function popularWebPages() 3 | returns refcursor 4 | AS $$ 5 | declare 6 | c1 refcursor := 'mycursor'; 7 | begin 8 | open c1 for 9 | select ws_web_page_sk,count(*) as cnt from web_sales_history, web_page 10 | where ws_web_page_sk = wp_web_page_sk 11 | group by ws_web_page_sk 12 | order by cnt desc 13 | limit 100; 14 | 15 | return c1; 16 | end; $$ 17 | language plpgsql 18 | 19 | 20 | select popularWebPages(); 21 | fetch all from mycursor; -------------------------------------------------------------------------------- /src/PLPgSQL/Table Valued UDFs/TVF3_maxProfitsales.sql: -------------------------------------------------------------------------------- 1 | --Compute store sales net profit ranking by state and city for a given year 2 | --and determine the five most profitable states. 3 | 4 | Create or replace Function maxProfitStates(givenYear int) 5 | RETURNS TABLE(state char(2), city varchar(60), profit decimal(15, 2)) 6 | language plpgsql 7 | as $$ 8 | begin 9 | return query 10 | select s_state, s_city, sum(ss_net_profit) as totalProfit 11 | from store_sales_history, store, date_dim 12 | where ss_store_sk = s_store_sk 13 | and ss_sold_date_sk = d_date_sk 14 | and d_year = @givenYear 15 | group by s_state, s_city 16 | order by totalProfit desc 17 | limit 5; 18 | end; $$ 19 | 20 | -------------------------------------------------------------------------------- /src/PLPgSQL/Table Valued UDFs/TVF4a_bestpromoWeb.sql: -------------------------------------------------------------------------------- 1 | --highest profit earning promos on the web 2 | 3 | create or replace function bestPromoWeb() 4 | returns TABLE(promo_sk int, profit_store decimal) 5 | language plpgsql 6 | as $$ 7 | begin 8 | return query 9 | select ws_promo_sk, sum(ws_net_profit) as posProfit from web_sales_history 10 | where ws_net_profit>0 11 | and ws_promo_sk is not NULL 12 | group by ws_promo_sk 13 | order by posProfit desc 14 | limit 5; 15 | 16 | end; $$ -------------------------------------------------------------------------------- /src/PLPgSQL/Table Valued UDFs/TVF4b_bestPromoCatalog.sql: -------------------------------------------------------------------------------- 1 | --highest profit earning promos on the catslog 2 | 3 | create or replace function bestPromoCatalog() 4 | returns TABLE(promo_sk int, profit_store decimal) 5 | language plpgsql 6 | as $$ 7 | begin 8 | return query 9 | select cs_promo_sk, sum(cs_net_profit) as posProfit from cataolog_sales_history 10 | where cs_net_profit>0 11 | and cs_promo_sk is not NULL 12 | group by cs_promo_sk 13 | order by posProfit desc 14 | limit 5; 15 | 16 | end; $$ -------------------------------------------------------------------------------- /src/PLPgSQL/Table Valued UDFs/TVF4c_bestPromoStore.sql: -------------------------------------------------------------------------------- 1 | --highest profit earning promos through stores 2 | 3 | create or replace function bestPromoStore() 4 | returns TABLE(promo_sk int, profit_store decimal) 5 | language plpgsql 6 | as $$ 7 | begin 8 | return query 9 | select ss_promo_sk, sum(ss_net_profit) as posProfit from store_sales_history 10 | where ss_net_profit>0 11 | and ss_promo_sk is not NULL 12 | group by ss_promo_sk 13 | order by posProfit desc 14 | limit 5; 15 | 16 | end; $$ 17 | 18 | -------------------------------------------------------------------------------- /src/PLPgSQL/Table Valued UDFs/TVF6_bestStoreForCategories.sql: -------------------------------------------------------------------------------- 1 | --top stores for each category based on the number of items sold 2 | 3 | CREATE TYPE bestStoreForCatgoryRet AS (category char(50), store int); 4 | 5 | CREATE OR REPLACE FUNCTION bestStoreForCatgory() 6 | RETURNS SETOF bestStoreForCatgoryRet AS 7 | $$ 8 | DECLARE 9 | cat char(50); 10 | maxStore int; 11 | retRow bestStoreForCatgoryRet; 12 | c1 cursor is (select distinct i_category from item where i_category is not null); 13 | BEGIN 14 | open c1; 15 | fetch c1 into cat; 16 | WHILE found loop 17 | maxStore := (select ss_store_sk from ( 18 | select ss_store_sk, count(*) as cnt 19 | from store_sales, item 20 | where ss_item_sk = i_item_sk and i_category = cat and ss_store_sk is not NULL 21 | group by ss_store_sk 22 | order by cnt desc 23 | limit 1)t); 24 | retRow := (cat, maxStore) :: bestStoreForCatgoryRet; 25 | fetch c1 into cat; 26 | RETURN NEXT retRow; 27 | END LOOP; 28 | 29 | RETURN; 30 | END 31 | $$ LANGUAGE PLPGSQL; -------------------------------------------------------------------------------- /src/PLPgSQL/Table Valued UDFs/TVF7_profitMonitoring.sql: -------------------------------------------------------------------------------- 1 | --analyse the profit of a store for a given duration. 2 | 3 | CREATE TYPE profitMonitoringRet AS (dt DATE, profit DECIMAL(15,2)); 4 | 5 | CREATE OR REPLACE FUNCTION profitMonitoring(startDate DATE, endDate DATE, givenStore INT) 6 | RETURNS SETOF profitMonitoringRet AS 7 | $$ 8 | DECLARE 9 | dateSk INT; 10 | dayProfit DECIMAL(15,2); 11 | retRow profitMonitoringRet; 12 | BEGIN 13 | 14 | IF startDate > endDate THEN 15 | RETURN; 16 | END IF; 17 | 18 | WHILE startDate <= endDate LOOP 19 | dateSk := (SELECT d_date_sk FROM date_dim WHERE d_date = startDate); 20 | dayProfit := (SELECT SUM(ss_net_profit) 21 | FROM store_sales 22 | WHERE ss_sold_date_sk = dateSk 23 | AND ss_store_sk = givenStore); 24 | retRow := (startDate, dayProfit) :: profitMonitoringRet; 25 | RETURN NEXT retRow; 26 | startDate := (startDate + interval '1 day') :: DATE; 27 | END LOOP; 28 | 29 | RETURN; 30 | END 31 | $$ LANGUAGE PLPGSQL; -------------------------------------------------------------------------------- /src/PLPgSQL/Triggers/trig_1_DateTableInsert.sql: -------------------------------------------------------------------------------- 1 | create or replace function dateTableTriggerFunc() 2 | returns trigger as 3 | $$ 4 | declare 5 | vyear int; vmonth int; vday int; dDay int; dMonth int; dYear int; 6 | vdate date; 7 | begin 8 | vyear := new.d_year; 9 | vmonth := new.d_moy; 10 | vday := new.d_dom; 11 | vdate := new.d_date; 12 | 13 | if(vyear is NULL or vyear<2100 or (vyear=2100 and vmonth=01 and vday=01)) then 14 | RAISE EXCEPTION 'illegal insert in date table'; 15 | end if; 16 | 17 | if(vdate is NULL and (vyear is NULL or vmonth is NULL or vday is NULL)) then 18 | RAISE EXCEPTION 'cannot insert incomplete date information'; 19 | end if; 20 | 21 | if(vdate is not NULL) then 22 | dDay := EXTRACT (DAY from vdate); 23 | dMonth := EXTRACT (MONTH from vdate); 24 | dYear := EXTRACT (YEAR from vdate); 25 | if((vyear is not NULL and vyear!=dYear) or (vmonth is not NULL and vmonth!=dMonth) or (vday is not NULL and vday!=dDay)) then 26 | RAISE EXCEPTION 'Inconsistent data values'; 27 | end if; 28 | end if; 29 | return new; 30 | end; 31 | $$ 32 | LANGUAGE 'plpgsql'; 33 | 34 | CREATE TRIGGER dateTableChanges 35 | after INSERT 36 | ON date_dim 37 | FOR EACH ROW 38 | execute procedure dateTableTriggerFunc(); 39 | 40 | --invocation 41 | insert into date_dim (d_date_sk, d_date_id, d_date, d_year, d_moy, d_dom) values (3488070, 'ACHOFIRSYCHGRUFG', '3022-01-19', 3022, 01, 19); -------------------------------------------------------------------------------- /src/PLPgSQL/Triggers/trig_2_CustAddressUpdate.sql: -------------------------------------------------------------------------------- 1 | create or replace function caUpdateTriggerFunc() 2 | returns trigger as 3 | $$ 4 | declare 5 | adr_sk int; adr_sk_varchar varchar(32767); 6 | begin 7 | adr_sk:= old.ca_address_sk; 8 | adr_sk_varchar := cast ( adr_sk as varchar); 9 | if(old.ca_country != new.ca_country)then 10 | insert into logTable values ('address' || adr_sk_varchar || 'changed to different country', current_timestamp ); 11 | elsif (old.ca_state != new.ca_state) then 12 | insert into logTable values ('address' || adr_sk_varchar || 'changed to different state', current_timestamp ); 13 | elsif (old.ca_city != new.ca_city) then 14 | insert into logTable values ('address' || adr_sk_varchar || 'changed to different city', current_timestamp ); 15 | end if; 16 | return new; 17 | end; 18 | $$ 19 | LANGUAGE 'plpgsql'; 20 | 21 | CREATE TRIGGER ca_update 22 | AFTER UPDATE 23 | ON customer_address 24 | FOR EACH ROW 25 | execute procedure caUpdateTriggerFunc(); 26 | 27 | 28 | --invocation 29 | update customer_address 30 | set ca_country= 31 | (case 32 | when (ca_address_sk<=5) then 'India' 33 | when (ca_address_sk>5 and ca_address_sk<=10) then 'NewZealand' 34 | when (ca_address_sk>10 and ca_address_sk<=15) then 'France' 35 | end 36 | ) 37 | where ca_address_sk<=15; -------------------------------------------------------------------------------- /src/PLPgSQL/Triggers/trig_3_PromoUpdate.sql: -------------------------------------------------------------------------------- 1 | create or replace function promoUpdateTrigerFunc() 2 | returns trigger as 3 | $$ 4 | begin 5 | if(old.p_discount_active='N' and new.p_discount_active='Y') then 6 | insert into logTable values( 'promo sk number ' || old.p_promo_sk || ' re-activated', current_timestamp); 7 | end if; 8 | return new; 9 | end; 10 | $$ 11 | LANGUAGE 'plpgsql'; 12 | 13 | 14 | CREATE TRIGGER promo_update 15 | AFTER UPDATE 16 | ON promotion 17 | FOR EACH ROW 18 | execute procedure promoUpdateTrigerFunc(); 19 | 20 | 21 | --invocation 22 | update promotion set p_discount_active='Y' where p_promo_sk>=200 and p_promo_sk<400 -------------------------------------------------------------------------------- /src/PLPgSQL/Triggers/trig_5_CatPageDelete.sql: -------------------------------------------------------------------------------- 1 | create or replace function deleteCatPageTriggerFunc() 2 | returns trigger as 3 | $$ 4 | begin 5 | if(old.cp_type='monthly ') then 6 | raise exception 'cannot delete page from monthly catalog as per policy'; 7 | else 8 | DELETE from catalog_sales where cs_catalog_page_sk = old.cp_catalog_page_sk; 9 | DELETE from catalog_returns where cr_catalog_page_sk = old.cp_catalog_page_sk; 10 | end if; 11 | return new; 12 | end; 13 | $$ 14 | LANGUAGE 'plpgsql'; 15 | 16 | CREATE TRIGGER deleteCatPage 17 | AFTER DELETE 18 | ON catalog_page 19 | FOR EACH ROW 20 | execute procedure deleteCatPageTriggerFunc(); 21 | 22 | --invocation query 23 | delete from catalog_page where cp_description like '%weapon%'; -------------------------------------------------------------------------------- /src/PLPgSQL/Triggers/trig_6_CustDelete.sql: -------------------------------------------------------------------------------- 1 | create or replace function deleteCustomerTriggerFunc() 2 | returns trigger as 3 | $$ 4 | begin 5 | UPDATE web_page set wp_customer_sk=NULL where wp_customer_sk = :old.c_customer_sk; 6 | DELETE from web_returns where wr_refunded_customer_sk = :old.c_customer_sk or wr_returning_customer_sk=:old.c_customer_sk; 7 | DELETE from catalog_returns where cr_refunded_customer_sk = :old.c_customer_sk or cr_returning_customer_sk=:old.c_customer_sk; 8 | DELETE from store_returns where sr_customer_sk = :old.c_customer_sk; 9 | 10 | DELETE from web_sales where ws_bill_customer_sk = :old.c_customer_sk or ws_ship_customer_sk=:old.c_customer_sk; 11 | DELETE from catalog_sales where cs_bill_customer_sk = :old.c_customer_sk or cs_ship_customer_sk=:old.c_customer_sk; 12 | DELETE from store_sales where ss_customer_sk =:old.c_customer_sk; 13 | return new; 14 | end; 15 | $$ 16 | LANGUAGE 'plpgsql'; 17 | 18 | CREATE TRIGGER delCust 19 | AFTER DELETE 20 | ON customer 21 | FOR EACH ROW 22 | execute procedure deleteCustomerTriggerFunc(); 23 | 24 | 25 | --invocation query 26 | delete from customer where c_customer_sk=1 -------------------------------------------------------------------------------- /src/PLSQL/Scalar UDFs/sudf_11_getRandomChar.sql: -------------------------------------------------------------------------------- 1 | CREATE or REPLACE FUNCTION genRandomChar(chars varchar, rand number) 2 | RETURN CHAR 3 | IS 4 | rslt CHAR(1) := NULL; 5 | resultIndex INT := NULL; 6 | BEGIN 7 | IF chars IS NULL then 8 | rslt := NULL; 9 | ELSIF LENGTH(chars) = 0 then 10 | rslt := NULL; 11 | ELSE 12 | resultIndex := genRandomInt(1, LENGTH(chars), rand); 13 | rslt := SUBSTR(chars, resultIndex, 1); 14 | END IF; 15 | RETURN rslt; 16 | END; 17 | -------------------------------------------------------------------------------- /src/PLSQL/Scalar UDFs/sudf_12_increaseInWebSpending.sql: -------------------------------------------------------------------------------- 1 | --Of the customers who purchased from web in both years 2000 and 2001, find positive increase in spending from one year to the other. 2 | 3 | create or replace function increaseInWebSpending(cust_sk int) 4 | return number 5 | is 6 | spending1 number; 7 | spending2 number; 8 | increase number; 9 | begin 10 | spending1:=0; 11 | spending2:=0; 12 | increase:=0; 13 | 14 | select sum(ws_net_paid_inc_ship_tax) into spending1 15 | from web_sales_history, date_dim 16 | where d_date_sk = ws_sold_date_sk 17 | and d_year = 2001 18 | and ws_bill_customer_sk=cust_sk; 19 | 20 | select sum(ws_net_paid_inc_ship_tax) into spending2 21 | from web_sales_history, date_dim 22 | where d_date_sk = ws_sold_date_sk 23 | and d_year = 2000 24 | and ws_bill_customer_sk=cust_sk; 25 | 26 | if(spending1 0; -------------------------------------------------------------------------------- /src/PLSQL/Scalar UDFs/sudf_13_maxPurchaseChannel.sql: -------------------------------------------------------------------------------- 1 | create or replace function maxPurchaseChannel(ckey number, fromDate number, toDate number) 2 | return varchar is 3 | pragma udf; 4 | numSalesFromStore number; 5 | numSalesFromCatalog number; 6 | numSalesFromWeb number; 7 | maxChannel varchar(50); 8 | begin 9 | select count(*) into numSalesFromStore 10 | from store_sales_history 11 | where ss_customer_sk = ckey and 12 | ss_sold_date_sk>=fromDate and 13 | ss_sold_date_sk<=toDate; 14 | 15 | select count(*) into numSalesFromCatalog 16 | from catalog_sales_history 17 | where cs_bill_customer_sk = ckey and 18 | cs_sold_date_sk>=fromDate and 19 | cs_sold_date_sk<=toDate; 20 | 21 | select count(*) into numSalesFromWeb 22 | from web_sales_history 23 | where ws_bill_customer_sk = ckey and 24 | ws_sold_date_sk>=fromDate and 25 | ws_sold_date_sk<=toDate; 26 | 27 | if(numSalesFromStore>numSalesFromCatalog)then 28 | maxChannel := 'Store'; 29 | if(numSalesfromWeb>numSalesFromStore)then 30 | maxChannel := 'Web'; 31 | end if; 32 | else 33 | maxChannel := 'Catalog'; 34 | if(numSalesfromWeb>numSalesFromCatalog)then 35 | maxChannel := 'Web'; 36 | end if; 37 | end if; 38 | 39 | return maxChannel; 40 | end; 41 | 42 | select c_customer_sk, maxPurchaseChannel(c_customer_sk, 2000, 2020) as channel from customer; 43 | -------------------------------------------------------------------------------- /src/PLSQL/Scalar UDFs/sudf_17_preferredChannel_wrtCount.sql: -------------------------------------------------------------------------------- 1 | create or replace function preferredChannel_wrtCount(cust_key int) 2 | return varchar 3 | is 4 | numWeb number; 5 | numStore number; 6 | numCat number; 7 | begin 8 | numWeb :=0; 9 | numStore :=0; 10 | numCat :=0; 11 | select count(*) into numWeb from web_sales_history where ws_bill_customer_sk=cust_key; 12 | select count(*) into numStore from store_sales_history where ss_customer_sk=cust_key; 13 | select count(*) into numCat from catalog_sales_history where cs_bill_customer_sk=cust_key; 14 | if(numWeb>=numStore and numWeb>=numCat) then 15 | return 'web'; 16 | end if; 17 | if(numStore>=numWeb and numStore>=numCat) then 18 | return 'store'; 19 | end if; 20 | if(numCat>=numStore and numCat>=numWeb) then 21 | return 'Catalog'; 22 | end if; 23 | return 'Logical error'; 24 | end; 25 | 26 | select c_customer_sk, dbo.preferredChannel(c_customer_sk) from customer; -------------------------------------------------------------------------------- /src/PLSQL/Scalar UDFs/sudf_1_totalLargePurchases.sql: -------------------------------------------------------------------------------- 1 | 2 | --Report the total catalog sales for customers in selected geographical regions or who made purchases of 3 | -- more than a given amount for a given year and quarter. 4 | 5 | create or replace function totalLargePurchases(givenState char, amount number, yr number, qtr number ) 6 | return number 7 | is 8 | pragma udf; 9 | largePurchase number; 10 | begin 11 | select sum(cs_net_paid_inc_ship_tax) into largePurchase 12 | from catalog_sales_history, customer, customer_address, date_dim 13 | where cs_bill_customer_sk = c_customer_sk and 14 | c_current_addr_sk = ca_address_sk and 15 | ca_state = givenState and 16 | cs_net_paid_inc_ship_tax >= amount and 17 | d_date_sk = cs_sold_date_sk and d_year = yr and d_qoy = qtr; 18 | return largePurchase; 19 | end; 20 | 21 | select ca_state, d_year, d_qoy, totalLargePurchases(ca_state, 1000, d_year, d_qoy) 22 | from customer_address_old, date_dim 23 | where d_year in (1998, 1999, 2000) and ca_state is not NULL 24 | group by ca_state, d_year, d_qoy 25 | order by ca_state, d_year, d_qoy; 26 | -------------------------------------------------------------------------------- /src/PLSQL/Scalar UDFs/sudf_20a_GetManufactSimple.sql: -------------------------------------------------------------------------------- 1 | create or replace function getManufact_simple(item int) 2 | return char 3 | is 4 | manufact char(50); 5 | begin 6 | select i_manufact into manufact from item where i_item_sk = item; 7 | return manufact; 8 | end; 9 | 10 | 11 | 12 | --complex calling query 13 | select maxsoldItem 14 | from 15 | (select ss_item_sk as maxSoldItem 16 | from 17 | (select ss_item_sk, sum(cnt) totalCnt 18 | from 19 | (select ss_item_sk, count(*) cnt from store_sales_history group by ss_item_sk 20 | union all 21 | select cs_item_sk, count(*) cnt from catalog_sales_history group by cs_item_sk 22 | union all 23 | select ws_item_sk, count(*) cnt from web_sales_history group by ws_item_sk )t1 24 | group by ss_item_sk)t2 25 | order by totalCnt desc 26 | fetch first 25000 rows only 27 | 28 | )t3 29 | where getManufact_simple(maxSoldItem) = 'oughtn st'; 30 | 31 | 32 | --Simple Calling Query 33 | select ws_item_sk 34 | from 35 | (select ws_item_sk, count(*) cnt from web_sales group by ws_item_sk order by cnt fetch first 25000 rows only)t1 36 | where getManufact_simple(ws_item_sk) = 'oughtn st'; -------------------------------------------------------------------------------- /src/PLSQL/Scalar UDFs/sudf_2_maxPromoChannel.sql: -------------------------------------------------------------------------------- 1 | create or replace function maxPromoChannel(year int) 2 | return varchar 3 | is 4 | begin 5 | return promoVsNoPromoItems(year); 6 | end; 7 | 8 | --invocation query 9 | select maxPromoChannel(2001) from DUAL; -------------------------------------------------------------------------------- /src/PLSQL/Scalar UDFs/sudf_3a_maxRetReasonWeb.sql: -------------------------------------------------------------------------------- 1 | create or replace function maxReturnReasonWeb 2 | return char is 3 | pragma udf; 4 | reason_desc char(100); 5 | reason_id char(16); 6 | begin 7 | 8 | select dt1.r_reason_id, dt1.r_reason_desc 9 | into reason_id, reason_desc 10 | from 11 | (select r_reason_id, r_reason_desc, count(*) as cnt 12 | from web_returns_history, reason 13 | where wr_reason_sk = r_reason_sk 14 | group by r_reason_id, r_reason_desc) dt1 15 | where dt1.cnt = (select max(cnt) 16 | from (select r_reason_id, r_reason_desc, count(*) as cnt 17 | from web_returns_history, reason 18 | where wr_reason_sk = r_reason_sk 19 | group by r_reason_id, r_reason_desc)dt2 20 | ); 21 | return reason_desc; 22 | end; 23 | 24 | select maxReturnReasonWeb as ans from DUAL; 25 | -------------------------------------------------------------------------------- /src/PLSQL/Scalar UDFs/sudf_3b_maxRetReasonCat.sql: -------------------------------------------------------------------------------- 1 | create or replace function maxReturnReasonCatalog 2 | return char 3 | is 4 | reason_desc char(100); 5 | reason_id char(16); 6 | begin 7 | 8 | select dt1.r_reason_id, dt1.r_reason_desc 9 | into reason_id, reason_desc 10 | from 11 | (select r_reason_id, r_reason_desc, count(*) as cnt 12 | from catalog_returns_history, reason 13 | where cr_reason_sk = r_reason_sk 14 | group by r_reason_id, r_reason_desc) dt1 15 | where dt1.cnt = (select max(cnt) 16 | from (select r_reason_id, r_reason_desc, count(*) as cnt 17 | from catalog_returns_history, reason 18 | where cr_reason_sk = r_reason_sk 19 | group by r_reason_id, r_reason_desc)dt2 20 | ); 21 | return reason_desc; 22 | end; 23 | 24 | select maxReturnReasonCatalog as ans from DUAL; 25 | 26 | 27 | -------------------------------------------------------------------------------- /src/PLSQL/Scalar UDFs/sudf_3c_maxRetReasonStore.sql: -------------------------------------------------------------------------------- 1 | create or replace function maxReturnReasonStore 2 | return char 3 | is 4 | reason_desc char(100); 5 | reason_id char(16); 6 | begin 7 | 8 | select dt1.r_reason_id, dt1.r_reason_desc 9 | into reason_id, reason_desc 10 | from 11 | (select r_reason_id, r_reason_desc, count(*) as cnt 12 | from store_returns_history, reason 13 | where sr_reason_sk = r_reason_sk 14 | group by r_reason_id, r_reason_desc) dt1 15 | where dt1.cnt = (select max(cnt) 16 | from (select r_reason_id, r_reason_desc, count(*) as cnt 17 | from store_returns_history, reason 18 | where sr_reason_sk = r_reason_sk 19 | group by r_reason_id, r_reason_desc)dt2 20 | ); 21 | return reason_desc; 22 | end; 23 | 24 | select maxReturnReasonStore as ans from DUAL; 25 | -------------------------------------------------------------------------------- /src/PLSQL/Scalar UDFs/sudf_4_getRandomInt.sql: -------------------------------------------------------------------------------- 1 | CREATE or REPLACE FUNCTION genRandomInt 2 | ( 3 | lower INT, 4 | upper INT, 5 | rand FLOAT 6 | ) 7 | RETURN INT 8 | IS 9 | result INT; 10 | range int; 11 | BEGIN 12 | range := upper - lower + 1; 13 | result := FLOOR(rand * range + lower); 14 | RETURN result; 15 | END; -------------------------------------------------------------------------------- /src/PLSQL/Scalar UDFs/sudf_5_MorEveRatio.sql: -------------------------------------------------------------------------------- 1 | --8) What is the ratio between the number of items sold over the internet in the morning (8 to 9am) to the number of 2 | --items sold in the evening (7 to 8pm) of customers with a specified number of dependents. 3 | 4 | create or replace function morningToEveRatio(dep int) 5 | return float 6 | is 7 | morningSale number; eveningSale number; ratio number; 8 | begin 9 | select count(*) into morningSale 10 | from web_sales_history, time_dim, customer_demographics 11 | where ws_sold_time_sk = t_time_sk and ws_bill_customer_sk = cd_demo_sk 12 | and t_hour>=8 and t_hour<=9 13 | and cd_dep_count=dep; 14 | 15 | select count(*) into eveningSale 16 | from web_sales_history, time_dim, customer_demographics 17 | where ws_sold_time_sk = t_time_sk and ws_bill_customer_sk = cd_demo_sk 18 | and t_hour>=19 and t_hour<=20 19 | and cd_dep_count=dep; 20 | 21 | ratio := morningSale/eveningSale; 22 | return ratio; 23 | end; 24 | 25 | 26 | 27 | select depCount, morningToEveRatio(depCount) from 28 | (select distinct cd_dep_count as depCount from customer_demographics)t; 29 | -------------------------------------------------------------------------------- /src/PLSQL/Scalar UDFs/sudf_6_totalDiscount.sql: -------------------------------------------------------------------------------- 1 | --Compute the total discount on web sales of items from a given manufacturer over a particular 90 day period for 2 | --sales whose discount exceeded 30% over the average discount of items from that manufacturer in that period of 3 | --time. 4 | 5 | create or replace function totalDiscount (manufacture_id number) 6 | return number IS 7 | average number; 8 | addition number; 9 | begin 10 | select avg(ws_ext_discount_amt) into average from web_sales_history, item 11 | where ws_item_sk = i_item_sk and i_manufact_id = manufacture_id; 12 | 13 | select sum(ws_ext_discount_amt) into addition from web_sales_history, item 14 | where ws_item_sk = i_item_sk and i_manufact_id = manufacture_id and 15 | ws_ext_discount_amt>1.3*average; 16 | return addition; 17 | end; 18 | 19 | select distinct i_manufact_id, totalDiscount(i_manufact_id) as totalDisc from item; 20 | -------------------------------------------------------------------------------- /src/PLSQL/Scalar UDFs/sudf_7_profitableManager.sql: -------------------------------------------------------------------------------- 1 | create or replace function profitableManager(manager varchar, year number) 2 | return number is 3 | netProfit number(15, 2); 4 | begin 5 | select sum(ss_net_profit) into netProfit 6 | from store, store_sales_history, date_dim 7 | where ss_sold_date_sk = d_date_sk 8 | and d_year=year 9 | and s_manager = manager 10 | and s_store_sk = ss_store_sk; 11 | if(netProfit>0) then 12 | return 1; 13 | end if; 14 | return 0; 15 | end; 16 | 17 | 18 | select s_manager from store where profitableManager(s_manager, 2001)<=0; 19 | 20 | 21 | -------------------------------------------------------------------------------- /src/PLSQL/Scalar UDFs/sudf_8_maxReturnClass.sql: -------------------------------------------------------------------------------- 1 | create or replace function maxReturnClass 2 | return char is --i_class is char(50) data type 3 | cnt number; 4 | cls char(50); 5 | maxClass char(50); 6 | maxReturn number; 7 | cursor c1 is 8 | select i_class, count(i_class) as cnt 9 | from catalog_returns, item 10 | where i_item_sk = cr_item_sk 11 | group by i_class; 12 | begin 13 | maxReturn := 0; 14 | open c1; 15 | loop 16 | fetch c1 into cls, cnt; 17 | exit when c1%NOTFOUND; 18 | if cnt>maxReturn then 19 | maxReturn := cnt; 20 | maxclass := cls; 21 | end if; 22 | end loop; 23 | close c1; 24 | return maxClass; 25 | end; 26 | 27 | 28 | select maxReturnClass from DUAL 29 | -------------------------------------------------------------------------------- /src/PLSQL/Scalar UDFs/sudf_9a_correlation_wealthShipCost_catalog.sql: -------------------------------------------------------------------------------- 1 | -- see if there is correlation betwen paying high shipping costs through catalog and 2 | --having a large number of high income inhabitants (at the state level)) 3 | 4 | create or replace function wealth_shipCostCorrelation_cat 5 | return varchar 6 | is 7 | numStates int; 8 | begin 9 | numStates := 0; 10 | 11 | select count(*) into numStates from 12 | (select ca_state from 13 | (select ca_state, sum(cs_ext_ship_cost) as sm 14 | from catalog_sales_history, customer_address 15 | where cs_bill_customer_sk = ca_address_sk and ca_state is not NULL 16 | group by ca_state 17 | order by sm desc 18 | fetch first 5 rows only)t1 19 | 20 | INTERSECT 21 | 22 | select ca_state from --states wth largest numeber high income people 23 | (select ca_state, count(*) as cnt 24 | from customer, household_demographics, customer_address 25 | where c_current_hdemo_sk = hd_demo_sk and c_current_addr_sk = ca_address_sk and hd_income_band_sk>=15 and ca_state is not NULL 26 | group by ca_state 27 | order by cnt desc 28 | fetch first 5 rows only)t2 29 | )t3 ; 30 | 31 | if(numStates>=4) then 32 | return 'hihgly correlated'; 33 | end if; 34 | if(numStates>=2 and numStates<=3) then 35 | return 'somewhat correlated'; 36 | end if; 37 | if(numStates>=0 and numStates<=1) then 38 | return 'no correlation'; 39 | end if; 40 | return 'error'; 41 | end; 42 | 43 | select wealth_shipCostCorrelation_cat from dual; -------------------------------------------------------------------------------- /src/PLSQL/Scalar UDFs/sudf_9b_correlation_wealthShipCost_web.sql: -------------------------------------------------------------------------------- 1 | -- see if there is correlation betwen paying high shipping costs through web and 2 | --having a large number of high income inhabitants (at the state level)) 3 | 4 | create or replace function wealth_shipCostCorrelation_web 5 | return varchar 6 | is 7 | numStates int; 8 | begin 9 | numStates := 0; 10 | 11 | select count(*) into numStates from 12 | (select ca_state from 13 | (select ca_state, sum(ws_ext_ship_cost) as sm 14 | from web_sales_history, customer_address 15 | where ws_bill_customer_sk = ca_address_sk and ca_state is not NULL 16 | group by ca_state 17 | order by sm desc 18 | fetch first 5 rows only)t1 19 | 20 | INTERSECT 21 | 22 | select ca_state from --states wth largest numeber high income people 23 | (select ca_state, count(*) as cnt 24 | from customer, household_demographics, customer_address 25 | where c_current_hdemo_sk = hd_demo_sk and c_current_addr_sk = ca_address_sk and hd_income_band_sk>=15 and ca_state is not NULL 26 | group by ca_state 27 | order by cnt desc 28 | fetch first 5 rows only)t2 29 | )t3 ; 30 | 31 | if(numStates>=4) then 32 | return 'hihgly correlated'; 33 | end if; 34 | if(numStates>=2 and numStates<=3) then 35 | return 'somewhat correlated'; 36 | end if; 37 | if(numStates>=0 and numStates<=1) then 38 | return 'no correlation'; 39 | end if; 40 | return 'error'; 41 | end; 42 | 43 | select wealth_shipCostCorrelation_web from dual; -------------------------------------------------------------------------------- /src/PLSQL/Stored Procedures/proc10_remove_item.sql: -------------------------------------------------------------------------------- 1 | CREATE PROCEDURE removeItem (item_sk int) 2 | is 3 | begin 4 | DELETE from item where i_item_sk = item_sk; 5 | END; -------------------------------------------------------------------------------- /src/PLSQL/Stored Procedures/proc11_repeatedShoppers.sql: -------------------------------------------------------------------------------- 1 | --people who shopped in 5 diffrent months in a given year from store 2 | 3 | create procedure repeatedShoppers (yr int) 4 | AS c1 sys_refcursor; 5 | BEGIN 6 | 7 | open c1 for 8 | select ss_customer_sk, count(*) 9 | from 10 | (select distinct ss_customer_sk, d_moy 11 | from store_sales_history, date_dim 12 | where ss_sold_date_sk = d_date_sk 13 | and d_year = yr 14 | and ss_customer_sk is not NULL 15 | )t 16 | group by ss_customer_sk 17 | having count(*)>=5 18 | order by count(*) desc; 19 | 20 | dbms_sql.return_result(c1); 21 | end; -------------------------------------------------------------------------------- /src/PLSQL/Stored Procedures/proc12_returnReason_highlyEducated.sql: -------------------------------------------------------------------------------- 1 | create procedure returnReason_highEducated 2 | AS c1 sys_refcursor; 3 | BEGIN 4 | 5 | open c1 for 6 | 7 | select r_reason_desc, count(*) as cnt 8 | from store_returns_history, customer_demographics, reason 9 | where sr_customer_sk = cd_demo_sk and sr_reason_sk = r_reason_sk and cd_education_status = 'Advanced Degree' 10 | group by r_reason_desc 11 | order by cnt desc; 12 | 13 | dbms_sql.return_result(c1); 14 | end; -------------------------------------------------------------------------------- /src/PLSQL/Stored Procedures/proc13_returnReason_lessEducated.sql: -------------------------------------------------------------------------------- 1 | create or replace procedure returnReason_lessEducated 2 | AS c1 sys_refcursor; 3 | BEGIN 4 | 5 | open c1 for 6 | 7 | select r_reason_desc, count(*) as cnt 8 | from store_returns_history, customer_demographics, reason 9 | where sr_customer_sk = cd_demo_sk and sr_reason_sk = r_reason_sk and cd_education_status = 'Primary' 10 | group by r_reason_desc 11 | order by cnt desc; 12 | 13 | dbms_sql.return_result(c1); 14 | end; -------------------------------------------------------------------------------- /src/PLSQL/Stored Procedures/proc14_salePerBrandCatalog.sql: -------------------------------------------------------------------------------- 1 | --Report the total extended sales price per item brand of a specific manufacturer for all catalog sales in a specific month 2 | --of the year. 3 | CREATE PROCEDURE salePerBrandCatalog (yr int, mnth int, manufacture int) 4 | AS c1 sys_refcursor; 5 | BEGIN 6 | 7 | open c1 for 8 | 9 | select i_brand, sum(cs_ext_sales_price) as totalSale 10 | from catalog_sales_history, item, date_dim 11 | where i_item_sk = cs_item_sk 12 | and i_manufact_id = manufacture 13 | and cs_sold_date_sk = d_date_sk 14 | and d_year = yr 15 | and d_moy = mnth 16 | group by i_brand; 17 | 18 | dbms_sql.return_result(c1); 19 | END; -------------------------------------------------------------------------------- /src/PLSQL/Stored Procedures/proc15_salePerBrandStore.sql: -------------------------------------------------------------------------------- 1 | --Report the total extended sales price per item brand of a specific manufacturer for all store sales in a specific month 2 | --of the year. 3 | CREATE PROCEDURE salePerBrandStore (yr int, mnth int, manufacture int) 4 | AS c1 sys_refcursor; 5 | BEGIN 6 | 7 | open c1 for 8 | select i_brand, sum(ss_ext_sales_price) as totalSale 9 | from store_sales_history, item, date_dim 10 | where i_item_sk = ss_item_sk 11 | and i_manufact_id = manufacture 12 | and ss_sold_date_sk = d_date_sk 13 | and d_year = yr 14 | and d_moy = mnth 15 | group by i_brand; 16 | 17 | dbms_sql.return_result(c1); 18 | END; -------------------------------------------------------------------------------- /src/PLSQL/Stored Procedures/proc16_salePerBrandWeb.sql: -------------------------------------------------------------------------------- 1 | --Report the total extended sales price per item brand of a specific manufacturer for all web sales in a specific month 2 | --of the year. 3 | CREATE PROCEDURE salePerBrandWeb (yr int, mnth int, manufacture int) 4 | AS c1 sys_refcursor; 5 | BEGIN 6 | 7 | open c1 for 8 | select i_brand, sum(ws_ext_sales_price) as totalSale 9 | from web_sales_history, item, date_dim 10 | where i_item_sk = ws_item_sk 11 | and i_manufact_id = manufacture 12 | and ws_sold_date_sk = d_date_sk 13 | and d_year = yr 14 | and d_moy = mnth 15 | group by i_brand; 16 | 17 | dbms_sql.return_result(c1); 18 | END; -------------------------------------------------------------------------------- /src/PLSQL/Stored Procedures/proc17_saleShoppers.sql: -------------------------------------------------------------------------------- 1 | --information on customers who purchased items from catalog that were on sale during a particular time 2 | CREATE PROCEDURE saleShoppers 3 | AS c1 sys_refcursor; 4 | BEGIN 5 | 6 | open c1 for 7 | select cs_bill_customer_sk as customer_sk, 8 | c_first_name, c_last_name, c_email_address, c_birth_year, 9 | cs_item_sk, d1.d_date as sold_date, 10 | d2.d_date as promo_strt_date, d3.d_date as promo_end_date, 11 | cs_promo_sk 12 | from catalog_sales_history, promotion, date_dim d1, date_dim d2, date_dim d3, customer 13 | where p_promo_sk = cs_promo_sk 14 | and cs_sold_date_sk = d1.d_date_sk 15 | and p_start_date_sk = d2.d_date_sk 16 | and p_end_date_sk = d3.d_date_sk 17 | and d1.d_date>=d2.d_date 18 | and d1.d_date<=d3.d_date 19 | and cs_bill_customer_sk = c_customer_sk; 20 | 21 | dbms_sql.return_result(c1); 22 | 23 | END; -------------------------------------------------------------------------------- /src/PLSQL/Stored Procedures/proc18_updateItemPrice.sql: -------------------------------------------------------------------------------- 1 | CREATE or replace PROCEDURE updateItemPrice (itemSk int, newPrice number) 2 | is 3 | BEGIN 4 | UPDATE item set i_current_price = newPrice 5 | where i_item_sk = itemSk 6 | and newPrice < 3*i_wholesale_cost; 7 | END; -------------------------------------------------------------------------------- /src/PLSQL/Stored Procedures/proc19_updateWebUrl.sql: -------------------------------------------------------------------------------- 1 | CREATE or replace PROCEDURE updateWebURL(oldUrl varchar, newUrl varchar) 2 | is 3 | BEGIN 4 | UPDATE web_page 5 | set wp_url = newUrl 6 | where wp_url = oldUrl; 7 | END; 8 | -------------------------------------------------------------------------------- /src/PLSQL/Stored Procedures/proc1_custDemoSaleInfo.sql: -------------------------------------------------------------------------------- 1 | --Calculate the average sales quantity, average sales price, average wholesale cost, total wholesale cost for store 2 | --sales of different customer types (based on marital status and gender) from the given state. 3 | 4 | CREATE or replace PROCEDURE customerDemographicSaleInfo (st char) 5 | AS 6 | c1 sys_refcursor; 7 | BEGIN 8 | open c1 for 9 | select ca_state, cd_gender, cd_marital_status, avg(ss_quantity) as avg_qty, avg(ss_sales_price) avg_sale, 10 | avg(ss_ext_wholesale_cost) as avg_wholsesale, sum(ss_ext_wholesale_cost) as sum_wholesale 11 | from store_sales_history, customer_demographics, customer, customer_address 12 | where ss_cdemo_sk = cd_demo_sk 13 | and c_customer_sk = ss_customer_sk 14 | and c_current_cdemo_sk = ca_address_sk 15 | and ca_state = st 16 | group by ca_state, cd_gender, cd_marital_status ; 17 | 18 | dbms_sql.return_result(c1); 19 | END; -------------------------------------------------------------------------------- /src/PLSQL/Stored Procedures/proc21_activatePromoCat.sql: -------------------------------------------------------------------------------- 1 | create or replace procedure activatePromoCat 2 | is 3 | promo_sk int; 4 | cursor c1 is select promo_sk from bestPromosCatalog(); 5 | begin 6 | open c1; 7 | loop 8 | fetch c1 into promo_sk; 9 | 10 | exit when c1%NOTFOUND; 11 | 12 | update promotion set p_end_date_sk = 10000000, p_discount_active='Y' 13 | where p_promo_sk = promo_sk; 14 | end LOOP; 15 | close c1; 16 | end; 17 | 18 | call activatePromoCat() -------------------------------------------------------------------------------- /src/PLSQL/Stored Procedures/proc22_activatePromoStore.sql: -------------------------------------------------------------------------------- 1 | create or replace procedure activatePromoStore 2 | is 3 | promo_sk int; 4 | cursor c1 is select promo_sk from bestPromoStore(); 5 | begin 6 | open c1; 7 | loop 8 | fetch c1 into promo_sk; 9 | 10 | exit when c1%NOTFOUND; 11 | 12 | update promotion set p_end_date_sk = 10000000, p_discount_active='Y' 13 | where p_promo_sk = promo_sk; 14 | end LOOP; 15 | close c1; 16 | end; -------------------------------------------------------------------------------- /src/PLSQL/Stored Procedures/proc23_activatePromoWeb.sql: -------------------------------------------------------------------------------- 1 | create or replace procedure activatePromoWeb 2 | is 3 | promo_sk int; 4 | cursor c1 is select promo_sk from bestPromosWeb(); 5 | begin 6 | open c1; 7 | loop 8 | fetch c1 into promo_sk; 9 | 10 | exit when c1%NOTFOUND; 11 | 12 | update promotion set p_end_date_sk = 10000000, p_discount_active='Y' 13 | where p_promo_sk = promo_sk; 14 | end LOOP; 15 | close c1; 16 | end; 17 | -------------------------------------------------------------------------------- /src/PLSQL/Stored Procedures/proc24_CreateRandmString.sql: -------------------------------------------------------------------------------- 1 | CREATE or replace PROCEDURE CreateRandomString (randomString IN OUT VARCHAR2) 2 | is 3 | stringLength INT :=16; 4 | chars VARCHAR(200); 5 | begin 6 | chars:= 'ABCDEFGHIJKLMNOPQRSTUVWXYZ'; 7 | randomString := ''; 8 | WHILE LENGTH(randomString) < stringLength loop 9 | randomString := randomString || genRandomChar(chars, dbms_random.random); 10 | END LOOP; 11 | END; 12 | 13 | 14 | -------------------------------------------------------------------------------- /src/PLSQL/Stored Procedures/proc25_delCatPage.sql: -------------------------------------------------------------------------------- 1 | create or replace procedure deleteCatalogPage( delContent varchar2, updateContent varchar2, updateDept varchar2) 2 | is 3 | begin 4 | if( delContent!='') then 5 | delete from catalog_page where cp_description like '%' || delContent || '%'; 6 | end if; 7 | 8 | if( updateContent!='') then 9 | update catalog_page set cp_department = updateDept where cp_description like '%' || updateDept || '%'; 10 | end if; 11 | end; 12 | 13 | --execution query 14 | call deleteCatalogPage ('weapon', 'patient', 'Medical') 15 | 16 | -------------------------------------------------------------------------------- /src/PLSQL/Stored Procedures/proc26_getReturnReason.sql: -------------------------------------------------------------------------------- 1 | --does look rather weird. Change logic. 2 | create procedure getReturnReason 3 | @reason_sk int, 4 | @reason_id nvarchar(16) 5 | as 6 | begin 7 | set nocount on 8 | 9 | if(@reason_sk = null and @reason_id = null) 10 | begin 11 | raiserror('Invalid arguments', 16, 1) 12 | end 13 | 14 | declare @curDate date = GetDate(); 15 | declare @day int = DAY(@curDate); 16 | declare @month int = MONTH(@curDate); 17 | declare @year int = YEAR(@curDate); 18 | 19 | select cr_reason_sk, r_reason_desc 20 | from catalog_returns, date_dim, reason 21 | where cr_returned_date_sk = d_date_sk 22 | and r_reason_sk = cr_reason_sk 23 | and d_moy <= @month and d_moy >= @month-5; 24 | end 25 | 26 | select * from reason 27 | -------------------------------------------------------------------------------- /src/PLSQL/Stored Procedures/proc27_getStoreByManager.sql: -------------------------------------------------------------------------------- 1 | create or replace procedure getStoreByManager(manager varchar2) 2 | as 3 | c1 sys_refcursor; 4 | cnt int; 5 | begin 6 | select count(*) into cnt from store where s_manager= manager; 7 | if (cnt=0) then 8 | raise_application_error (-20111, 'No stores operated by this manager'); 9 | 10 | else 11 | open c1 for 12 | select s_street_number, s_street_name, s_street_type, s_suite_number, s_city, s_county, s_state,s_zip, s_country 13 | from store 14 | where s_manager = manager; 15 | 16 | dbms_sql.return_result(c1); 17 | end if; 18 | end; -------------------------------------------------------------------------------- /src/PLSQL/Stored Procedures/proc28_insertCallCenter.sql: -------------------------------------------------------------------------------- 1 | CREATE or replace PROCEDURE InsertCallCenter ( strt_date date, end_date date, cc_closed_date int, open_date int , cc_name varchar, 2 | ske int, ide char, cls varchar, numEmpl int, sz int, hrs char, 3 | mgr varchar, mkt_id int, mkt_cls char, mkt_desc varchar, 4 | Mktmanager varchar, div int, divName varchar, company int, company_name char, 5 | st_num char, stName varchar, stType char, cc_suite char, 6 | city varchar, county varchar, stt char, zip char, 7 | country varchar, offs number, taxPercent number) 8 | is 9 | cnt int; 10 | BEGIN 11 | select count(*) into cnt from call_center where cc_call_center_sk = ske; 12 | if (cnt=0) then 13 | insert into call_center values ( strt_date, end_date, cc_closed_date, open_date, cc_name, ske, ide, cls, numEmpl, sz, hrs, 14 | mgr, mkt_id, mkt_cls, mkt_desc, Mktmanager, div, divName, company, 15 | company_name, st_num, stName, stType, cc_suite, cit, county, stt, zip, country, 16 | offs, taxPercent); 17 | end if; 18 | END; -------------------------------------------------------------------------------- /src/PLSQL/Stored Procedures/proc29_insertNewShipCarrier.sql: -------------------------------------------------------------------------------- 1 | create or replace procedure newShippingCarrier(typ char, code char, nam char, 2 | contract char) 3 | is 4 | randomString varchar(16); 5 | ske int; 6 | ide char(16); 7 | begin 8 | select max(sm_ship_mode_sk)+1 into ske from ship_mode; 9 | randomString:=''; 10 | CreateRandomString (randomString); 11 | ide := randomString; 12 | 13 | insert into ship_mode (sm_ship_mode_sk, sm_ship_mode_id, sm_type, sm_code, sm_carrier, sm_contract) 14 | values (ske, ide, typ, code, nam, contract); 15 | 16 | end; 17 | 18 | --calling query 19 | call newShippingCarrier ('FORTNIGHT', 'SEA', 'SHIPCo', '83hdjk0hf8j') -------------------------------------------------------------------------------- /src/PLSQL/Stored Procedures/proc2_excessReturn_web.sql: -------------------------------------------------------------------------------- 1 | CREATE PROCEDURE excessReturn_web 2 | AS c1 sys_refcursor; 3 | BEGIN 4 | 5 | open c1 for 6 | WITH ReturnTable 7 | AS (SELECT wr_returning_customer_sk, 8 | ca_state, 9 | Sum(wr_return_amt) as returnAmt 10 | FROM web_returns_history, 11 | customer_address, 12 | date_dim 13 | WHERE wr_returned_date_sk = d_date_sk 14 | and wr_returning_addr_sk = ca_address_sk 15 | AND d_year = 2001 16 | GROUP BY wr_returning_customer_sk, 17 | ca_state) 18 | SELECT c_customer_id, c_salutation, c_first_name, c_last_name, c_email_address, c_birth_year, c_birth_country 19 | FROM ReturnTable tr1, 20 | customer_address ca1, 21 | customer 22 | WHERE tr1.returnAmt > (SELECT Avg(returnAmt) * 1.2 23 | FROM ReturnTable tr2 24 | WHERE tr1.ca_state = tr2.ca_state) 25 | AND ca_address_sk = c_current_addr_sk 26 | AND tr1.wr_returning_customer_sk = c_customer_sk 27 | AND ca1.ca_state = 'TX' ; 28 | 29 | dbms_sql.return_result(c1); 30 | END; 31 | -------------------------------------------------------------------------------- /src/PLSQL/Stored Procedures/proc30_lossByEdcated-Risky.sql: -------------------------------------------------------------------------------- 1 | --Total loss incurred on each channel by credit risky, highly educated men with non-zero dependents 2 | 3 | create or replace procedure lossByEducated_risky 4 | as 5 | c1 sys_refcursor; 6 | web_loss decimal(15,2); 7 | cat_loss decimal(15,2); 8 | total_loss decimal(15,2); 9 | begin 10 | select sum(ws_net_profit) into web_loss 11 | from web_sales_history 12 | where ws_bill_cdemo_sk in 13 | (select cd_demo_sk from customer_demographics where cd_gender='M' and cd_education_status = 'Advanced Degree' 14 | and cd_dep_count>0 and cd_credit_rating = 'High Risk') 15 | and ws_net_profit<0; 16 | 17 | select sum(cs_net_profit) into cat_loss 18 | from catalog_sales_history 19 | where cs_bill_cdemo_sk in 20 | (select cd_demo_sk from customer_demographics where cd_gender='M' and cd_education_status = 'Advanced Degree' 21 | and cd_dep_count>0 and cd_credit_rating = 'High Risk') 22 | and cs_net_profit<0; 23 | 24 | open c1 for 25 | select web_loss + cat_loss into total_loss from dual; 26 | 27 | dbms_sql.return_result(c1); 28 | end; -------------------------------------------------------------------------------- /src/PLSQL/Stored Procedures/proc31_maxSaleElectronicsMonth.sql: -------------------------------------------------------------------------------- 1 | --which months registered the highest store sale of electronics for a given 3 year period. 2 | 3 | --which months registered the highest sale of electronics for 3 year period startig at the given year. 4 | 5 | create or replace procedure maxSaleElectronicsMonth(yr int) 6 | as 7 | c1 sys_refcursor; 8 | month1 int; month2 int; month3 int; 9 | yr1 int; yr2 int; yr3 int; 10 | begin 11 | select d_moy into month1 12 | from store_sales_history, item, date_dim 13 | where ss_item_sk = i_item_sk and ss_sold_date_sk=d_date_sk and d_year = yr and i_category='Electronics' 14 | group by d_moy 15 | order by count(*) desc 16 | fetch first 1 rows only; 17 | 18 | select d_moy into month2 19 | from store_sales_history, item, date_dim 20 | where ss_item_sk = i_item_sk and ss_sold_date_sk=d_date_sk and d_year = yr+1 and i_category='Electronics' 21 | group by d_moy 22 | order by count(*) desc 23 | fetch first 1 rows only; 24 | 25 | select d_moy into month3 26 | from store_sales_history, item, date_dim 27 | where ss_item_sk = i_item_sk and ss_sold_date_sk=d_date_sk and d_year = yr+2 and i_category='Electronics' 28 | group by d_moy 29 | order by count(*) desc 30 | fetch first 1 rows only; 31 | 32 | open c1 for 33 | select month1 , month2 , month3 34 | into yr1, yr2, yr3 from dual; 35 | 36 | dbms_sql.return_result(c1); 37 | end; -------------------------------------------------------------------------------- /src/PLSQL/Stored Procedures/proc32_maxSaleJewelryMonth.sql: -------------------------------------------------------------------------------- 1 | --which months registered the highest sale of jewelry for 3 year period startig at the given year. 2 | 3 | create or replace procedure maxSaleJewelryMonth(yr int) 4 | as 5 | c1 sys_refcursor; 6 | month1 int; month2 int; month3 int; 7 | yr1 int; yr2 int; yr3 int; 8 | begin 9 | select d_moy into month1 10 | from store_sales_history, item, date_dim 11 | where ss_item_sk = i_item_sk and ss_sold_date_sk=d_date_sk and d_year = yr and i_category='jewelry' 12 | group by d_moy 13 | order by count(*) desc 14 | fetch first 1 rows only; 15 | 16 | select d_moy into month2 17 | from store_sales_history, item, date_dim 18 | where ss_item_sk = i_item_sk and ss_sold_date_sk=d_date_sk and d_year = yr+1 and i_category='jewelry' 19 | group by d_moy 20 | order by count(*) desc 21 | fetch first 1 rows only; 22 | 23 | select d_moy into month3 24 | from store_sales_history, item, date_dim 25 | where ss_item_sk = i_item_sk and ss_sold_date_sk=d_date_sk and d_year = yr+2 and i_category='jewelry' 26 | group by d_moy 27 | order by count(*) desc 28 | fetch first 1 rows only; 29 | 30 | open c1 for 31 | select month1 , month2 , month3 32 | into yr1, yr2, yr3 from dual; 33 | 34 | dbms_sql.return_result(c1); 35 | end; 36 | -------------------------------------------------------------------------------- /src/PLSQL/Stored Procedures/proc33_newCatalogPage.sql: -------------------------------------------------------------------------------- 1 | create or replace procedure newCatalogPage( strtDate int, endDate int, dept varchar, catNumber int, 2 | pgNum int, dsc varchar, typevarchar varchar) 3 | is 4 | randomString varchar(16); 5 | ske int; 6 | ide char(16); 7 | begin 8 | select max(cp_catalog_page_sk)+1 into ske from catalog_page; 9 | randomString :=''; 10 | CreateRandomString (randomString); 11 | ide := randomString; 12 | insert into catalog_page (cp_catalog_page_sk, cp_catalog_page_id, cp_start_date_sk, cp_end_date_sk, 13 | cp_department, cp_catalog_number, cp_catalog_page_number, cp_description, cp_type) 14 | values ( ske, ide, strtDate, endDate, dept, catNumber, pgNum, dsc, typevarchar); 15 | end; 16 | -------------------------------------------------------------------------------- /src/PLSQL/Stored Procedures/proc34_newPromotion.sql: -------------------------------------------------------------------------------- 1 | create procedure new_promotion( item_sk int, start_date int, end_date int, cst number) 2 | is 3 | newSk int; maxSk int; 4 | begin 5 | select max(p_promo_sk) into maxSk from promotion; 6 | newSk := maxSk+1; 7 | 8 | insert into promotion(p_promo_sk, p_start_date_sk, p_end_date_sk, p_item_sk, p_cost, p_discount_active) 9 | values ( newSk, start_date, end_date, item_sk, cst, 'Y'); 10 | end; -------------------------------------------------------------------------------- /src/PLSQL/Stored Procedures/proc35_newStore.sql: -------------------------------------------------------------------------------- 1 | create procedure newStore( store_sk int, mgr varchar) 2 | is 3 | cnt int; 4 | begin 5 | select count(*) into cnt from store where s_store_sk= store_sk; 6 | if (cnt=0) then 7 | insert into store (s_store_sk, s_store_id, s_manager) values ( store_sk, DEFAULT, mgr); 8 | else 9 | update store set s_manager = mgr where s_store_sk = store_sk; 10 | end if; 11 | end; -------------------------------------------------------------------------------- /src/PLSQL/Stored Procedures/proc36_newWarehouse.sql: -------------------------------------------------------------------------------- 1 | --add a new warehouse to the database: 2 | create or replace procedure newWarehouse( nm varchar, sqFt int, streetNo char, stName varchar, 3 | suite char, city varchar, county varchar, st char, 4 | zip char, country varchar) 5 | is 6 | randomString varchar(16); 7 | ske int; 8 | ide char(16); 9 | begin 10 | select max(w_warehouse_sk)+1 into ske from warehouse; 11 | 12 | CreateRandomString (randomString); 13 | ide := randomString; 14 | insert into warehouse (w_warehouse_sk, w_warehouse_id, w_warehouse_name, w_warehouse_sq_ft, w_street_number, 15 | w_street_name, w_suite_number, w_city, w_county, w_state, w_zip, w_country) 16 | values ( ske, ide, nm, sqFt, streetNo, stName, suite, city, county, st, zip, country); 17 | 18 | end; -------------------------------------------------------------------------------- /src/PLSQL/Stored Procedures/proc37_procesStoreReturn.sql: -------------------------------------------------------------------------------- 1 | --new return request 2 | 3 | create or replace procedure processReturn_store 4 | (item_sk int, cust_sk int, reason_sk int, ticketNum int, returnQty int, returnReason char) 5 | is 6 | curDate date; 7 | dateSk int; 8 | cnt int; 9 | begin 10 | select sysdate into curdate from dual; 11 | select d_date_sk into dateSk from date_dim where d_date = curDate; 12 | insert into store_returns (sr_returned_date_sk, sr_item_sk, sr_customer_sk, sr_reason_sk, sr_ticket_number, sr_return_quantity) 13 | values (dateSk, item_sk, cust_sk, reason_sk, ticketNum, returnQty); 14 | 15 | select count(*) into cnt from reason where r_reason_sk=reason_sk; 16 | if (cnt>0) then 17 | return; 18 | else 19 | insert into reason (r_reason_sk, r_reason_desc) values (reason_sk, returnReason); 20 | end if; 21 | end; 22 | -------------------------------------------------------------------------------- /src/PLSQL/Stored Procedures/proc3_excessReturnCustInfo.sql: -------------------------------------------------------------------------------- 1 | CREATE or replace PROCEDURE getExcessReturnCustInfo 2 | AS 3 | c1 sys_refcursor; 4 | BEGIN 5 | open c1 for 6 | WITH totalReturn 7 | AS (SELECT sr_customer_sk, 8 | sr_store_sk, 9 | Sum(sr_return_amt) as returnAmt 10 | FROM store_returns_history, 11 | date_dim 12 | WHERE sr_returned_date_sk = d_date_sk 13 | AND d_year = 2001 14 | GROUP BY sr_customer_sk, 15 | sr_store_sk) 16 | SELECT distinct c_customer_id, c_email_address, cd_gender, cd_credit_rating 17 | FROM totalReturn tr1, 18 | store, 19 | customer, 20 | customer_demographics 21 | WHERE tr1.returnAmt > (SELECT Avg(returnAmt) * 1.2 22 | FROM totalReturn tr2 23 | WHERE tr1.sr_store_sk = tr2.sr_store_sk) 24 | AND s_store_sk = tr1.sr_store_sk 25 | AND tr1.sr_customer_sk = c_customer_sk 26 | AND c_current_cdemo_sk = cd_demo_sk; 27 | 28 | dbms_sql.return_result(c1); 29 | 30 | end; 31 | -------------------------------------------------------------------------------- /src/PLSQL/Stored Procedures/proc44_cusWithIncomeInRange.sql: -------------------------------------------------------------------------------- 1 | --List all customers living in a specified city, in a given income band 2 | create or replace procedure cusWithIncomeInRange(city varchar, givenIb int) 3 | as 4 | cust int; ib int; hhd int; 5 | cursor c1 is 6 | select c_customer_sk 7 | from customer, customer_address 8 | where c_current_addr_sk=ca_address_sk and ca_city = city; 9 | begin 10 | open c1; 11 | loop 12 | fetch c1 into cust; 13 | exit when c1%NOTFOUND; 14 | select c_current_hdemo_sk into hhd from customer where c_customer_sk = cust; 15 | select hd_income_band_sk into ib from household_demographics where hd_demo_sk = hhd; 16 | if(ib = givenIb) then 17 | dbms_output.put_line(cust); 18 | end if; 19 | fetch c1 into cust; 20 | end loop; 21 | end; 22 | 23 | --execution query 24 | call cusWithIncomeInRange ('Hopewell', 2) 25 | 26 | -------------------------------------------------------------------------------- /src/PLSQL/Stored Procedures/proc45_moreOnlineThanStore.sql: -------------------------------------------------------------------------------- 1 | -- Customers who spend more money online than in stores 2 | 3 | create or replace procedure moreOnlineThanStore 4 | as 5 | preferredChannel varchar(50); 6 | cust int; 7 | cursor c1 is 8 | select c_customer_sk from customer; 9 | begin 10 | open c1; 11 | loop 12 | fetch c1 into cust; 13 | exit when c1%NOTFOUND; 14 | select preferredChannel_wrtExpenditure(cust) into preferredChannel from dual; 15 | if(preferredChannel='catalog' or preferredChannel='web') then 16 | dbms_output.put_line(cust); 17 | end if; 18 | end loop; 19 | end; -------------------------------------------------------------------------------- /src/PLSQL/Stored Procedures/proc46_processReturn.sql: -------------------------------------------------------------------------------- 1 | --new return request 2 | 3 | create or replace procedure processReturn 4 | (channel char, item_sk int, cust_sk int, reason_sk int, orderNum int, returnQty int, returnReason char, 5 | retAmt number, refundAmt number) 6 | is 7 | curDate date; 8 | dateSk int; cnt int; 9 | randomString VARCHAR(16); 10 | reason_id varchar(16); 11 | begin 12 | SELECT SYSDATE into curDate FROM DUAL; 13 | select d_date_sk into dateSk from date_dim where d_date = curDate; 14 | if(channel='c') then 15 | insert into catalog_returns (cr_returned_date_sk, cr_item_sk, cr_refunded_customer_sk, cr_reason_sk, 16 | cr_order_number, cr_return_quantity, cr_return_amt_inc_tax, cr_refunded_cash) 17 | values (dateSk, item_sk, cust_sk, reason_sk, orderNum, returnQty, retAmt, refundAmt); 18 | end if; 19 | if(channel='w') then 20 | insert into web_returns (wr_returned_date_sk, wr_item_sk, wr_refunded_customer_sk, wr_reason_sk, 21 | wr_order_number, wr_return_quantity, wr_return_amt_inc_tax, wr_refunded_cash) 22 | values (dateSk, item_sk, cust_sk, reason_sk, orderNum, returnQty , retAmt, refundAmt); 23 | end if; 24 | select count(*) into cnt from reason where r_reason_sk=reason_sk; 25 | if(cnt!=0) then 26 | return; 27 | else 28 | CreateRandomString (randomString); 29 | reason_id := randomString; 30 | insert into reason (r_reason_sk, r_reason_id, r_reason_desc) values (reason_sk, reason_id, returnReason); 31 | end if; 32 | end; -------------------------------------------------------------------------------- /src/PLSQL/Stored Procedures/proc4_getCustomerInfo.sql: -------------------------------------------------------------------------------- 1 | create or replace procedure getCustomerInfo(custKey int) 2 | AS c1 sys_refcursor; 3 | BEGIN 4 | open c1 for 5 | select c_salutation, c_first_name, c_last_name, c_birth_year, c_email_address, 6 | ca_street_number, ca_street_name, ca_suite_number, ca_city, ca_county, ca_country 7 | from customer, customer_address 8 | where c_current_addr_sk = ca_address_sk 9 | and c_customer_sk = custKey; 10 | 11 | dbms_sql.return_result(c1); 12 | end; -------------------------------------------------------------------------------- /src/PLSQL/Stored Procedures/proc52_catalogOrderCancellation.sql: -------------------------------------------------------------------------------- 1 | --process cancellation of an order from catalog and record reason in the reason table. 2 | 3 | create or replace procedure catalogOrderCancellation (item_sk int, orderNo int, reasonId int) 4 | is 5 | shipDate date; curDate date; 6 | dateDiff int; reasonSk int; 7 | ide VARCHAR(16); 8 | cnt int; 9 | begin 10 | select count(*) into cnt from catalog_sales where cs_item_sk=item_sk and cs_order_number=orderNo; 11 | if (cnt=0) then 12 | raise_application_error(-20111, 'invalid order'); 13 | return; 14 | end if; 15 | select sysdate into curDate from dual; 16 | select d_date into shipDate from catalog_sales, date_dim 17 | where cs_ship_date_sk=d_date_sk and cs_item_sk=item_sk and cs_order_number=orderNo; 18 | dateDiff := shipDate - curDate; 19 | if(dateDiff<=0) then 20 | raise_application_error (-20111, 'item already shipped. Try returning later.'); 21 | return; 22 | else 23 | delete from catalog_sales where cs_item_sk=item_sk and cs_order_number=orderNo; 24 | select count(*) into cnt from reason where r_reason_sk=reasonId; 25 | if (cnt!=0) then 26 | return; 27 | else 28 | select max(r_reason_sk)+1 into reasonSk from reason; 29 | CreateRandomString (ide); 30 | insert into reason (r_reason_sk, r_reason_id) values (reasonSk, ide); 31 | end if; 32 | end if; 33 | end; 34 | 35 | -------------------------------------------------------------------------------- /src/PLSQL/Stored Procedures/proc57_webOrderCancellation.sql: -------------------------------------------------------------------------------- 1 | --process cancellation of an order fromm web and record reason in the reason table. 2 | 3 | create or replace procedure webOrderCancellation (item_sk int, orderNo int, reasonId int) 4 | is 5 | shipDate date; curDate date; 6 | dateDiff int; reasonSk int; 7 | ide VARCHAR(16); 8 | cnt int; 9 | begin 10 | select count(*) into cnt from web_sales where ws_item_sk=item_sk and ws_order_number=orderNo; 11 | if (cnt=0) then 12 | raise_application_error(-20111, 'invalid order'); 13 | return; 14 | end if; 15 | select sysdate into curDate from dual; 16 | select d_date into shipdate from web_sales, date_dim 17 | where ws_ship_date_sk=d_date_sk and ws_item_sk=item_sk and ws_order_number=orderNo; 18 | dateDiff := shipDate - curDate; 19 | if(dateDiff<=0) then 20 | raise_application_error (-20111, 'item already shipped. Try returning later.'); 21 | return; 22 | else 23 | delete from web_sales where ws_item_sk=item_sk and ws_order_number=orderNo; 24 | select count(*) into cnt from reason where r_reason_sk=reasonId; 25 | if (cnt!=0) then 26 | return; 27 | else 28 | select max(r_reason_sk)+1 into reasonSk from reason; 29 | CreateRandomString (ide); 30 | insert into reason (r_reason_sk, r_reason_id) values (reasonSk, ide); 31 | end if; 32 | end if; 33 | end; -------------------------------------------------------------------------------- /src/PLSQL/Stored Procedures/proc5_getImmigrantCust.sql: -------------------------------------------------------------------------------- 1 | create procedure getImmigrantCustomers 2 | AS c1 sys_refcursor; 3 | begin 4 | open c1 for 5 | select c_customer_sk, c_birth_country, ca_state as currentState, cd_gender, cd_marital_status, 6 | cd_education_status, ib_lower_bound, ib_upper_bound, 7 | cd_credit_rating, cd_dep_count 8 | from customer, customer_address, household_demographics, income_band, customer_demographics 9 | where c_current_addr_sk = ca_address_sk 10 | and c_birth_country != ca_country 11 | and c_current_hdemo_sk=hd_demo_sk 12 | and hd_income_band_sk = ib_income_band_sk 13 | and cd_demo_sk = c_current_cdemo_sk 14 | and c_customer_sk is not NULL; 15 | 16 | dbms_sql.return_result(c1); 17 | end; 18 | -------------------------------------------------------------------------------- /src/PLSQL/Stored Procedures/proc62_totalCustLoss.sql: -------------------------------------------------------------------------------- 1 | create or replace procedure custTotalLoss(returnReason char) 2 | as 3 | c3 sys_refcursor; 4 | orderNo int; item int; 5 | reasonSk int; 6 | soldAmt decimal(7, 2); retCredit decimal(7, 2); 7 | totalCustLoss decimal(15, 0); totalLossAns decimal(15, 0); 8 | cursor c1 is 9 | select wr_order_number, wr_item_sk, wr_refunded_cash from web_returns where wr_reason_sk=1; 10 | cursor c2 is 11 | select cr_order_number, cr_item_sk, cr_refunded_cash from catalog_returns where cr_reason_sk=1; 12 | begin 13 | totalCustLoss :=0 ; 14 | select r_reason_sk into reasonSk from reason where r_reason_desc=returnReason; 15 | open c1; 16 | loop 17 | fetch c1 into orderNo, item, retCredit; 18 | exit when c1%NOTFOUND; 19 | select ws_net_paid_inc_ship_tax into soldAmt from web_sales where ws_order_number = orderNo and ws_item_sk=item; 20 | totalCustLoss := totalCustLoss + soldAmt - retCredit ; 21 | end loop; 22 | close c1; 23 | 24 | open c2; 25 | loop 26 | fetch c2 into orderNo, item, retCredit; 27 | exit when c1%NOTFOUND; 28 | select cs_net_paid_inc_ship_tax into soldAmt from catalog_sales where cs_order_number = orderNo and cs_item_sk=item; 29 | totalCustLoss := totalCustLoss + soldAmt - retCredit ; 30 | end loop; 31 | close c2; 32 | 33 | open c3 for 34 | select totalCustLoss into totalLossAns from dual; 35 | 36 | dbms_sql.return_result(c3); 37 | end; -------------------------------------------------------------------------------- /src/PLSQL/Stored Procedures/proc6_getNativeCust.sql: -------------------------------------------------------------------------------- 1 | create or replace procedure getNativeCustomers 2 | AS 3 | c1 sys_refcursor; 4 | BEGIN 5 | open c1 for 6 | select c_customer_sk, ca_state, cd_gender, cd_marital_status, 7 | cd_education_status, ib_lower_bound, ib_upper_bound, 8 | cd_credit_rating, cd_dep_count 9 | from customer, customer_address, household_demographics, income_band, customer_demographics 10 | where c_current_addr_sk = ca_address_sk 11 | and c_birth_country=ca_country 12 | and c_current_hdemo_sk=hd_demo_sk 13 | and hd_income_band_sk = ib_income_band_sk 14 | and cd_demo_sk = c_current_cdemo_sk 15 | and c_customer_sk is not NULL; 16 | 17 | dbms_sql.return_result(c1); 18 | end; 19 | 20 | call getNativeCustomers() -------------------------------------------------------------------------------- /src/PLSQL/Stored Procedures/proc7_lowIncomeCustWithHighPurchase.sql: -------------------------------------------------------------------------------- 1 | --cusotmers belonging to a low income band and who made purchases of more than a given amount. 2 | 3 | 4 | CREATE or replace PROCEDURE lowIncomeCustomerWithHighPurchaseAmount(amount number) 5 | as 6 | c1 sys_refcursor; 7 | begin 8 | open c1 for 9 | select distinct ss_customer_sk, ib_income_band_sk 10 | from store_sales_history, household_demographics, income_band 11 | where ss_hdemo_sk = hd_demo_sk 12 | and hd_income_band_sk = ib_income_band_sk 13 | and ss_net_paid_inc_tax>amount 14 | and ib_income_band_sk<=4; 15 | dbms_sql.return_result(c1); 16 | END; -------------------------------------------------------------------------------- /src/PLSQL/Stored Procedures/proc9_popularWP.sql: -------------------------------------------------------------------------------- 1 | --how may people shopped from a web_page 2 | create or replace procedure popularWebPages 3 | as 4 | c1 sys_refcursor; 5 | begin 6 | open c1 for 7 | select ws_web_page_sk,count(*) as cnt from web_sales_history, web_page 8 | where ws_web_page_sk = wp_web_page_sk 9 | group by ws_web_page_sk 10 | order by cnt desc 11 | fetch first 100 rows only; 12 | 13 | dbms_sql.return_result(c1); 14 | end; -------------------------------------------------------------------------------- /src/PLSQL/Table Valued UDFs/TVF3_maxProfitStates.sql: -------------------------------------------------------------------------------- 1 | --Compute store sales net profit ranking by state and city for a given year 2 | --and determine the five most profitable states. 3 | CREATE or REPLACE TYPE profitRank_o IS object( 4 | state char(2), city varchar(60), profit decimal(15, 2) 5 | ); 6 | / 7 | 8 | Create or REPLACE type profitRank_t is TABLE OF profitRank_o; 9 | 10 | 11 | Create or replace Function maxProfitStates(givenYear int) 12 | RETURN profitRank_t 13 | is 14 | profitTable profitRank_t; 15 | begin 16 | select profitRank_o(t.s_state, t.s_city, t.totalProfit) 17 | bulk collect into profitTable 18 | from 19 | (select s_state, s_city, sum(ss_net_profit) as totalProfit 20 | from store_sales, store, date_dim 21 | where ss_store_sk = s_store_sk 22 | and ss_sold_date_sk = d_date_sk 23 | and d_year = givenYear 24 | group by s_state, s_city 25 | order by totalProfit desc)t 26 | where rownum<=5 27 | ; 28 | 29 | return profitTable; 30 | end; 31 | 32 | 33 | -------------------------------------------------------------------------------- /src/PLSQL/Table Valued UDFs/TVF4a_bestPromoWeb.sql: -------------------------------------------------------------------------------- 1 | CREATE or REPLACE TYPE bestPromo_o IS object( 2 | promo_sk number, profit_store number 3 | ); 4 | / 5 | 6 | Create or REPLACE type bestPromo_t is TABLE OF bestPromo_o; 7 | 8 | 9 | create or replace function bestPromosWeb 10 | return bestPromo_t 11 | is 12 | promoTable bestPromo_t; 13 | begin 14 | 15 | select bestPromo_o(t.ws_promo_sk, t.posProfit) 16 | bulk collect into promoTable 17 | from 18 | (select ws_promo_sk, sum(ws_net_profit) as posProfit from web_sales_history 19 | where ws_net_profit>0 20 | and ws_promo_sk is not NULL 21 | group by ws_promo_sk 22 | order by posProfit desc)t 23 | where rownum<=5; 24 | 25 | return promoTable; 26 | end; 27 | 28 | 29 | 30 | 31 | 32 | -------------------------------------------------------------------------------- /src/PLSQL/Table Valued UDFs/TVF4b_bestPromoCatalog.sql: -------------------------------------------------------------------------------- 1 | CREATE or REPLACE TYPE bestPromo_o IS object( 2 | promo_sk number, profit_store number 3 | ); 4 | / 5 | 6 | Create or REPLACE type bestPromo_t is TABLE OF bestPromo_o; 7 | 8 | create or replace function bestPromosCatalog 9 | return bestPromo_t 10 | is 11 | promoTable bestPromo_t; 12 | begin 13 | 14 | select bestPromo_o(t.cs_promo_sk, t.posProfit) 15 | bulk collect into promoTable 16 | from 17 | (select cs_promo_sk, sum(cs_net_profit) as posProfit 18 | from catalog_sales_history 19 | where cs_net_profit>0 20 | and cs_promo_sk is not NULL 21 | group by cs_promo_sk 22 | order by posProfit desc)t 23 | where rownum<=5; 24 | 25 | return promoTable; 26 | 27 | end; 28 | 29 | 30 | 31 | 32 | -------------------------------------------------------------------------------- /src/PLSQL/Table Valued UDFs/TVF4c_bestPromoStore.sql: -------------------------------------------------------------------------------- 1 | CREATE or REPLACE TYPE bestPromo_o IS object( 2 | promo_sk number, profit_store number 3 | ); 4 | / 5 | 6 | Create or REPLACE type bestPromo_t is TABLE OF bestPromo_o; 7 | 8 | create or replace function bestPromoStore 9 | return bestPromo_t 10 | is 11 | promoTable bestPromo_t; 12 | begin 13 | 14 | select bestPromo_o(t.ss_promo_sk, t.posProfit) 15 | bulk collect into promoTable 16 | from 17 | (select ss_promo_sk, sum(ss_net_profit) as posProfit 18 | from store_sales_history 19 | where ss_net_profit>0 20 | and ss_promo_sk is not NULL 21 | group by ss_promo_sk 22 | order by posProfit desc)t 23 | where rownum<=5; 24 | 25 | return promoTable; 26 | 27 | end; 28 | 29 | 30 | 31 | 32 | 33 | -------------------------------------------------------------------------------- /src/PLSQL/Table Valued UDFs/TVF6_bestStoreForCategories.sql: -------------------------------------------------------------------------------- 1 | CREATE or REPLACE TYPE cat_o IS object( 2 | category char(50), store int 3 | ); 4 | / 5 | 6 | Create or REPLACE type cat_t is TABLE OF cat_o; 7 | 8 | --top stores for each category based on the number of items sold 9 | create or replace function bestStoreForCatgory 10 | return cat_t 11 | is 12 | catTable cat_t; 13 | cat char(50); 14 | maxStore int; 15 | cursor c1 is (select distinct i_category from item where i_category is not null); 16 | begin 17 | open c1; 18 | loop 19 | fetch c1 into cat; 20 | select ss_store_sk into maxStore 21 | from ( 22 | select ss_store_sk, count(*) as cnt 23 | from store_sales, item 24 | where ss_item_sk = i_item_sk and i_category = cat and ss_store_sk is not NULL 25 | group by ss_store_sk 26 | order by cnt desc 27 | ) 28 | where rownum<=1; 29 | 30 | catTable.extend; 31 | catTable(catTable.last) := cat_o(cat, maxStore); 32 | end loop; 33 | close c1; 34 | return catTable; 35 | end; 36 | -------------------------------------------------------------------------------- /src/PLSQL/Table Valued UDFs/TVF7_profitMonitoring.sql: -------------------------------------------------------------------------------- 1 | --analyse the profit of a store for a given duration. 2 | CREATE or REPLACE TYPE profit_o IS object( 3 | dt date, profit decimal(15, 2) 4 | ); 5 | / 6 | 7 | Create or REPLACE type profit_t is TABLE OF profit_o; 8 | 9 | 10 | create or replace function profitMonitoring(startDate date, endDate date, givenStore int) 11 | return profit_t 12 | is 13 | profitTable profit_t; 14 | dateSk int; 15 | newdate date; 16 | dayProfit decimal(15, 2); 17 | begin 18 | if(startDate>endDate) then 19 | return profitTable; 20 | end if; 21 | newDate:=startDate; 22 | while(newDate<=endDate) 23 | loop 24 | select d_date_sk into dateSk from date_dim where d_date = startDate; 25 | 26 | select sum(ss_net_profit) into dayprofit 27 | from store_sales_history 28 | where ss_sold_date_sk=dateSk and ss_store_sk = givenStore; 29 | 30 | profitTable.extend; 31 | profitTable(profitTable.last) := profit_o(startDate, dayProfit); 32 | newDate:=startDate+1; 33 | end loop; 34 | return profitTable; 35 | end; 36 | -------------------------------------------------------------------------------- /src/PLSQL/Triggers/trigger1_afterInsertdate.sql: -------------------------------------------------------------------------------- 1 | CREATE or REPLACE TRIGGER dateTableChanges 2 | AFTER INSERT 3 | ON date_dim 4 | FOR EACH ROW 5 | DECLARE 6 | vyear int; vmonth int; vday int; dDay int; dMonth int; dYear int; 7 | vdate date; 8 | BEGIN 9 | vyear := :new.d_year; 10 | vmonth := :new.d_moy; 11 | vday := :new.d_dom; 12 | vdate := :new.d_date; 13 | 14 | if(vyear is NULL or vyear<2100 or (vyear=2100 and vmonth=01 and vday=01)) then 15 | raise_application_error(-20100, 'illegal insert in date table'); 16 | return; 17 | end if; 18 | 19 | if(vdate is NULL and (vyear is NULL or vmonth is NULL or vday is NULL)) then 20 | raise_application_error(-20100, 'cannot insert incomplete date information'); 21 | return; 22 | end if; 23 | 24 | if(vdate is not NULL) then 25 | dDay := EXTRACT (DAY from vdate); 26 | dMonth := EXTRACT (MONTH from vdate); 27 | dYear := EXTRACT (YEAR from vdate); 28 | if((vyear is not NULL and vyear!=dYear) or (vmonth is not NULL and vmonth!=dMonth) or (vday is not NULL and vday!=dDay)) then 29 | raise_application_error(-20100, 'Inconsistent data values'); 30 | return; 31 | end if; 32 | end if; 33 | END; 34 | 35 | --invocation query 36 | insert into date_dim (d_date_sk, d_date_id, d_date, d_year, d_moy, d_dom) values (3488073, 'ACHOFIRSYCHGRUFG', '19-JAN-3020', 3020, 01, 19); -------------------------------------------------------------------------------- /src/PLSQL/Triggers/trigger2_afterUpdateCA.sql: -------------------------------------------------------------------------------- 1 | CREATE OR replace TRIGGER ca_update 2 | AFTER UPDATE 3 | ON customer_address 4 | FOR EACH ROW 5 | DECLARE 6 | adr_sk int; adr_sk_varchar varchar(32767); 7 | BEGIN 8 | adr_sk:= :old.ca_address_sk; 9 | adr_sk_varchar := TO_CHAR(adr_sk); 10 | if(:old.ca_country != :new.ca_country)then 11 | insert into logTable values ('address' || adr_sk_varchar || 'changed to different country', current_timestamp ); 12 | elsif (:old.ca_state != :new.ca_state) then 13 | insert into logTable values ('address' || adr_sk_varchar || 'changed to different state', current_timestamp ); 14 | elsif (:old.ca_city != :new.ca_city) then 15 | insert into logTable values ('address' || adr_sk_varchar || 'changed to different city', current_timestamp ); 16 | end if; 17 | END; 18 | 19 | 20 | 21 | --invocation query 22 | update customer_address 23 | set ca_country= 24 | (case 25 | when (ca_address_sk<=5) then 'India' 26 | when (ca_address_sk>5 and ca_address_sk<=10) then 'NewZealand' 27 | when (ca_address_sk>10 and ca_address_sk<=15) then 'France' 28 | end 29 | ) 30 | where ca_address_sk<=15; 31 | -------------------------------------------------------------------------------- /src/PLSQL/Triggers/trigger3_afterUpdate_promo.sql: -------------------------------------------------------------------------------- 1 | CREATE TRIGGER promo_update 2 | AFTER UPDATE 3 | ON promotion 4 | FOR EACH ROW 5 | BEGIN 6 | 7 | if(:old.p_discount_active='N' and :new.p_discount_active='Y') then 8 | insert into logTable values( 'promo sk number ' || :old.p_promo_sk || ' re-activated', current_timestamp); 9 | end if; 10 | END; 11 | 12 | --invocation query 13 | update promotion set p_discount_active='Y' where p_promo_sk>=200 and p_promo_sk<400 14 | -------------------------------------------------------------------------------- /src/PLSQL/Triggers/trigger5_afterdelCatPage.sql: -------------------------------------------------------------------------------- 1 | CREATE or REPLACE TRIGGER deleteCatPage 2 | AFTER DELETE 3 | ON catalog_page 4 | FOR EACH ROW 5 | begin 6 | if(:old.cp_type='monthly ') then 7 | raise_application_error(-20100, 'cannot delete page from monthly catalog as per policy'); 8 | else 9 | DELETE from catalog_sales where cs_catalog_page_sk = :old.cp_catalog_page_sk; 10 | DELETE from catalog_returns where cr_catalog_page_sk = :old.cp_catalog_page_sk; 11 | end if; 12 | end; 13 | 14 | --invocation query 15 | delete from catalog_page where cp_description like '%weapon%'; -------------------------------------------------------------------------------- /src/PLSQL/Triggers/trigger6_afterDelCust.sql: -------------------------------------------------------------------------------- 1 | CREATE or REPLACE TRIGGER deleteCustomer 2 | AFTER DELETE 3 | ON customer 4 | FOR EACH ROW 5 | BEGIN 6 | UPDATE web_page set wp_customer_sk=NULL where wp_customer_sk = :old.c_customer_sk; 7 | DELETE from web_returns where wr_refunded_customer_sk = :old.c_customer_sk or wr_returning_customer_sk=:old.c_customer_sk; 8 | DELETE from catalog_returns where cr_refunded_customer_sk = :old.c_customer_sk or cr_returning_customer_sk=:old.c_customer_sk; 9 | DELETE from store_returns where sr_customer_sk = :old.c_customer_sk; 10 | 11 | DELETE from web_sales where ws_bill_customer_sk = :old.c_customer_sk or ws_ship_customer_sk=:old.c_customer_sk; 12 | DELETE from catalog_sales where cs_bill_customer_sk = :old.c_customer_sk or cs_ship_customer_sk=:old.c_customer_sk; 13 | DELETE from store_sales where ss_customer_sk =:old.c_customer_sk; 14 | END; 15 | 16 | 17 | --invocation query 18 | delete from customer where c_customer_sk=1; -------------------------------------------------------------------------------- /src/T-SQL/Scalar UDFs/sudf_10_isListDistinct.sql: -------------------------------------------------------------------------------- 1 | -- Check if a given list of varchars is distinct. Called from sudf_14_sameManager 2 | 3 | CREATE or alter FUNCTION isListDistinct(@List VARCHAR(MAX), @Delim CHAR) 4 | RETURNS 5 | BIT 6 | AS 7 | BEGIN 8 | DECLARE @Part VARCHAR(MAX), @Pos INT 9 | SET @List = LTRIM(RTRIM(@List)) + @Delim 10 | SET @Pos = CHARINDEX(@Delim, @List, 1) 11 | WHILE (@Pos > 0) 12 | BEGIN 13 | SET @Part = LTRIM(RTRIM(LEFT(@List, @Pos))) 14 | SET @list = SUBSTRING(@list, @pos+1, LEN(@list)) 15 | IF (CHARINDEX(@Part, @List, 1) != 0) 16 | RETURN 0; 17 | 18 | SET @Pos = CHARINDEX(@Delim, @List, 1) 19 | END 20 | 21 | RETURN 1; 22 | END -------------------------------------------------------------------------------- /src/T-SQL/Scalar UDFs/sudf_11_genRandomChar.sql: -------------------------------------------------------------------------------- 1 | --Pick a random character from a given list of characters. This is called from stored procedure proc_24_CreateRandomString 2 | 3 | CREATE FUNCTION genRandomChar 4 | ( 5 | @chars VARCHAR(MAX), 6 | @rand FLOAT 7 | ) 8 | RETURNS CHAR(1) 9 | AS 10 | BEGIN 11 | DECLARE @result CHAR(1) = NULL; 12 | DECLARE @resultIndex INT = NULL; 13 | IF @chars IS NULL 14 | SET @result = NULL; 15 | ELSE IF LEN(@chars) = 0 16 | SET @result = NULL 17 | ELSE 18 | BEGIN 19 | SET @resultIndex = dbo.genRandomInt(1, LEN(@chars), @rand); 20 | SET @result = SUBSTRING(@chars, @resultIndex, 1); 21 | END 22 | 23 | RETURN @result; 24 | END 25 | -------------------------------------------------------------------------------- /src/T-SQL/Scalar UDFs/sudf_12_increaseInWebSpending.sql: -------------------------------------------------------------------------------- 1 | -- Find out the increase in web spending by a given customer from year 2000 to 2001. 2 | 3 | create or alter function increaseInWebSpending(@cust_sk int) 4 | returns decimal(15, 2) 5 | as 6 | begin 7 | declare @spending1 decimal(15, 2)=0; 8 | declare @spending2 decimal(15, 2)=0; 9 | declare @increase decimal(15, 2)=0; 10 | set @spending1 = (select sum(ws_net_paid_inc_ship_tax) 11 | from web_sales_history, date_dim 12 | where d_date_sk = ws_sold_date_sk 13 | and d_year = 2001 14 | and ws_bill_customer_sk=@cust_sk); 15 | set @spending2 = (select sum(ws_net_paid_inc_ship_tax) 16 | from web_sales_history, date_dim 17 | where d_date_sk = ws_sold_date_sk 18 | and d_year = 2000 19 | and ws_bill_customer_sk=@cust_sk); 20 | if(@spending1<@spending2) 21 | return -1; 22 | else 23 | set @increase = @spending1-@spending2; 24 | return @increase; 25 | 26 | end 27 | go 28 | 29 | --invocation query 30 | select t.ws_bill_customer_sk 31 | from 32 | (select ws_bill_customer_sk 33 | from web_sales_history, date_dim 34 | where d_date_sk = ws_sold_date_sk 35 | and d_year = 2000 and d_moy=1 and ws_bill_customer_sk is not NULL 36 | 37 | INTERSECT 38 | 39 | select ws_bill_customer_sk 40 | from web_sales_history, date_dim 41 | where d_date_sk = ws_sold_date_sk 42 | and d_year = 2001 and d_moy=1 and ws_bill_customer_sk is not NULL 43 | )t 44 | where dbo.increaseInWebSpending(t.ws_bill_customer_sk) > 0; 45 | -------------------------------------------------------------------------------- /src/T-SQL/Scalar UDFs/sudf_13_maxPurchaseChannel.sql: -------------------------------------------------------------------------------- 1 | create or alter function maxPurchaseChannel(@ckey int, @fromDateSk int, @toDateSk int) 2 | returns varchar(50) as 3 | begin 4 | declare @numSalesFromStore int; 5 | declare @numSalesFromCatalog int; 6 | declare @numSalesFromWeb int; 7 | declare @maxChannel varchar(50); 8 | set @numSalesFromStore = (select count(*) 9 | from store_sales_history 10 | where ss_customer_sk = @ckey and 11 | ss_sold_date_sk>=@fromDateSk and 12 | ss_sold_date_sk<=@toDateSk); 13 | 14 | set @numSalesFromCatalog = (select count(*) 15 | from catalog_sales_history 16 | where cs_bill_customer_sk = @ckey and 17 | cs_sold_date_sk>=@fromDateSk and 18 | cs_sold_date_sk<=@toDateSk); 19 | 20 | set @numSalesFromWeb = (select count(*) 21 | from web_sales_history 22 | where ws_bill_customer_sk = @ckey and 23 | ws_sold_date_sk>=@fromDateSk and 24 | ws_sold_date_sk<=@toDateSk); 25 | 26 | if(@numSalesFromStore>@numSalesFromCatalog) 27 | begin 28 | set @maxChannel = 'Store'; 29 | if(@numSalesfromWeb>@numSalesFromStore) 30 | begin 31 | set @maxChannel = 'Web'; 32 | end 33 | end 34 | else 35 | begin 36 | set @maxChannel = 'Catalog'; 37 | if(@numSalesfromWeb>@numSalesFromCatalog) 38 | begin 39 | set @maxChannel = 'Web'; 40 | end 41 | end 42 | 43 | return @maxChannel; 44 | end 45 | go 46 | 47 | --invocation query 48 | select c_customer_sk, dbo.maxPurchaseChannel(c_customer_sk, 2000, 2020) as channel from customer 49 | -------------------------------------------------------------------------------- /src/T-SQL/Scalar UDFs/sudf_14_sameManager.sql: -------------------------------------------------------------------------------- 1 | --check if multiple large stores(>250 employees) are managed by the same person. 2 | 3 | create or alter function sameManagerForLargeStores() 4 | returns bit 5 | as 6 | begin 7 | declare @manag varchar(40); 8 | declare @allManag nvarchar(max); 9 | set @allManag=''; 10 | declare c1 cursor static for 11 | (select s_manager from store where s_number_employees>250); 12 | open c1; 13 | fetch next from c1 into @manag; 14 | while(@@FETCH_STATUS=0) 15 | begin 16 | set @allManag=@allManag+@manag+', '; 17 | fetch next from c1 into @manag; 18 | end 19 | close c1; 20 | deallocate c1; 21 | return 1-dbo.isListDistinct(@allManag, ','); 22 | end 23 | go -------------------------------------------------------------------------------- /src/T-SQL/Scalar UDFs/sudf_17_preferredChannel_wrtCount.sql: -------------------------------------------------------------------------------- 1 | --for all customers, find out the preferred channel wrt number of orders made. 2 | 3 | create or alter function preferredChannel_wrtCount(@cust_key int) 4 | returns varchar(50) 5 | as 6 | begin 7 | declare @numWeb int=0; 8 | declare @numStore int=0; 9 | declare @numCat int=0; 10 | set @numWeb = (select count(*) from web_sales_history where ws_bill_customer_sk=@cust_key); 11 | set @numStore = (select count(*) from store_sales_history where ss_customer_sk=@cust_key); 12 | set @numCat = (select count(*) from catalog_sales_history where cs_bill_customer_sk=@cust_key); 13 | if(@numWeb>=@numStore and @numWeb>=@numCat) 14 | return 'web'; 15 | if(@numStore>=@numWeb and @numStore>=@numCat) 16 | return 'store'; 17 | if(@numCat>=@numStore and @numCat>=@numWeb) 18 | return 'Catalog'; 19 | return 'Logical error'; 20 | end 21 | go 22 | 23 | --invocation query 24 | select c_customer_sk, dbo.preferredChannel(c_customer_sk) from customer; -------------------------------------------------------------------------------- /src/T-SQL/Scalar UDFs/sudf_18_preferredChannel_wrtExpenditure.sql: -------------------------------------------------------------------------------- 1 | --for all customers, find out the preferred channel wrt money spent. 2 | create or alter function preferredChannel_wrtExpenditure(@cust_key int) 3 | returns varchar(50) 4 | as 5 | begin 6 | declare @numWeb decimal(15, 2)=0; 7 | declare @numStore decimal(15, 2)=0; 8 | declare @numCat decimal(15, 2)=0; 9 | if exists (select * from web_sales_history where ws_bill_customer_sk=@cust_key) 10 | set @numWeb = (select sum(ws_net_paid_inc_ship_tax) from web_sales_history where ws_bill_customer_sk=@cust_key); 11 | if exists (select * from store_sales_history where ss_customer_sk=@cust_key) 12 | set @numStore = (select sum(ss_net_paid_inc_tax) from store_sales_history where ss_customer_sk=@cust_key); 13 | if exists (select * from catalog_sales_history where cs_bill_customer_sk=@cust_key) 14 | set @numCat = (select sum(cs_net_paid_inc_ship_tax) from catalog_sales_history where cs_bill_customer_sk=@cust_key); 15 | if(@numWeb>=@numStore and @numWeb>=@numCat) 16 | return 'web'; 17 | if(@numStore>=@numWeb and @numStore>=@numCat) 18 | return 'store'; 19 | if(@numCat>=@numStore and @numCat>=@numWeb) 20 | return 'Catalog'; 21 | return 'Logical error'; 22 | end 23 | go 24 | 25 | --invocation Query 26 | select c_customer_sk, dbo.preferredChannel_wrtExpenditure(c_customer_sk) from customer; 27 | -------------------------------------------------------------------------------- /src/T-SQL/Scalar UDFs/sudf_1_totalLargePurchase.sql: -------------------------------------------------------------------------------- 1 | --Report the total catalog sales for customers from a given state who made purchases of 2 | -- more than a given amount in a given year and quarter. 3 | 4 | create or alter function totalLargePurchases(@givenState char (2), @amount decimal(7, 2), @yr int, @qtr int) 5 | returns decimal(15, 2) 6 | as 7 | begin 8 | return 9 | (select sum(cs_net_paid_inc_ship_tax) 10 | from catalog_sales_history, customer, customer_address, date_dim 11 | where cs_bill_customer_sk = c_customer_sk and 12 | c_current_addr_sk = ca_address_sk and 13 | d_date_sk = cs_sold_date_sk and 14 | ca_state = @givenState and 15 | cs_net_paid_inc_ship_tax >= @amount and 16 | d_year = @yr and d_qoy = @qtr 17 | ) 18 | end 19 | go 20 | 21 | 22 | --invocation query 23 | select ca_state, d_year, d_qoy, dbo.totalLargePurchases(ca_state, 1000, d_year, d_qoy) 24 | from customer_address, date_dim 25 | where d_year in (1998, 1999, 2000) and ca_state is not NULL 26 | group by ca_state, d_year, d_qoy 27 | order by ca_state, d_year, d_qoy; -------------------------------------------------------------------------------- /src/T-SQL/Scalar UDFs/sudf_20a_GetManufactSimple.sql: -------------------------------------------------------------------------------- 1 | create or alter function getManufact_simple(@item int) 2 | returns char(50) 3 | as 4 | begin 5 | return (select i_manufact from item where i_item_sk = @item) 6 | end 7 | go 8 | 9 | 10 | --complex calling query 11 | select maxsoldItem 12 | from 13 | (select top 25000 ss_item_sk as maxSoldItem 14 | from 15 | (select ss_item_sk, sum(cnt) totalCnt 16 | from 17 | (select ss_item_sk, count(*) cnt from store_sales_history group by ss_item_sk 18 | union all 19 | select cs_item_sk, count(*) cnt from catalog_sales_history group by cs_item_sk 20 | union all 21 | select ws_item_sk, count(*) cnt from web_sales_history group by ws_item_sk )t1 22 | group by ss_item_sk)t2 23 | order by totalCnt desc 24 | )t3 25 | where dbo.getManufact_simple(maxSoldItem) = 'oughtn st' 26 | 27 | 28 | --Simple Calling Query 29 | select ws_item_sk 30 | from 31 | (select top 25000 ws_item_sk, count(*) cnt from web_sales group by ws_item_sk order by cnt)t1 32 | where dbo.getManufact_simple(ws_item_sk) = 'oughtn st'; -------------------------------------------------------------------------------- /src/T-SQL/Scalar UDFs/sudf_2_maxPromoChannel.sql: -------------------------------------------------------------------------------- 1 | create or alter function maxPromoChannel(@year int) 2 | returns varchar(20) 3 | as 4 | begin 5 | return dbo.promoVsNoPromoItems(@year); 6 | end 7 | go 8 | 9 | --invocation query 10 | select dbo.maxPromoChannel(2001); 11 | go 12 | -------------------------------------------------------------------------------- /src/T-SQL/Scalar UDFs/sudf_3a_maxRetReasonWeb.sql: -------------------------------------------------------------------------------- 1 | --most frequent reason for returns on the web 2 | 3 | create or alter function maxReturnReasonWeb() 4 | returns char(100) as 5 | begin 6 | 7 | declare @r_reason_desc char(100), @reason_id char(16); 8 | 9 | select @reason_id = r_reason_id, @r_reason_desc = r_reason_desc 10 | from 11 | (select r_reason_id, r_reason_desc, count(*) as cnt 12 | from web_returns_history, reason 13 | where wr_reason_sk = r_reason_sk 14 | group by r_reason_id, r_reason_desc) dt1 15 | where dt1.cnt = (select max(cnt) 16 | from (select r_reason_id, r_reason_desc, count(*) as cnt 17 | from web_returns_history, reason 18 | where wr_reason_sk = r_reason_sk 19 | group by r_reason_id, r_reason_desc)dt2 20 | ) 21 | 22 | return @r_reason_desc; 23 | end 24 | go -------------------------------------------------------------------------------- /src/T-SQL/Scalar UDFs/sudf_3b_maxRetReasonCat.sql: -------------------------------------------------------------------------------- 1 | --Most frequent reason for returns on catalog 2 | 3 | create or alter function maxReturnReasonCatalog() 4 | returns char(100) as 5 | begin 6 | declare @r_reason_desc char(100), @reason_id char(16); 7 | select @reason_id = r_reason_id, @r_reason_desc = r_reason_desc 8 | from 9 | (select r_reason_id, r_reason_desc, count(*) as cnt 10 | from catalog_returns_history, reason 11 | where cr_reason_sk = r_reason_sk 12 | group by r_reason_id, r_reason_desc) dt1 13 | where dt1.cnt = (select max(cnt) 14 | from (select r_reason_id, r_reason_desc, count(*) as cnt 15 | from catalog_returns_history, reason 16 | where cr_reason_sk = r_reason_sk 17 | group by r_reason_id, r_reason_desc)dt2 18 | ) 19 | return @r_reason_desc; 20 | end 21 | go -------------------------------------------------------------------------------- /src/T-SQL/Scalar UDFs/sudf_3c_maxRetReasonStore.sql: -------------------------------------------------------------------------------- 1 | --Most frequent reason for returns through stores 2 | 3 | create or alter function maxReturnReasonStore() 4 | returns char(100) as 5 | begin 6 | 7 | declare @r_reason_desc char(100), @reason_id char(16); 8 | select @reason_id = r_reason_id, @r_reason_desc = r_reason_desc 9 | from 10 | (select r_reason_id, r_reason_desc, count(*) as cnt 11 | from store_returns_history, reason 12 | where sr_reason_sk = r_reason_sk 13 | group by r_reason_id, r_reason_desc) dt1 14 | where dt1.cnt = (select max(cnt) 15 | from (select r_reason_id, r_reason_desc, count(*) as cnt 16 | from store_returns_history, reason 17 | where sr_reason_sk = r_reason_sk 18 | group by r_reason_id, r_reason_desc)dt2 19 | ) 20 | return @r_reason_desc; 21 | end 22 | go -------------------------------------------------------------------------------- /src/T-SQL/Scalar UDFs/sudf_4_getRandomInt.sql: -------------------------------------------------------------------------------- 1 | --Generate a random integer between given lower and upper bounds Called from sudf_11_genRandomChar 2 | 3 | CREATE FUNCTION genRandomInt 4 | ( 5 | @lower INT, 6 | @upper INT, 7 | @rand FLOAT 8 | ) 9 | RETURNS INT 10 | AS 11 | BEGIN 12 | DECLARE @result INT; 13 | DECLARE @range int = @upper - @lower + 1; 14 | SET @result = FLOOR(@rand * @range + @lower); 15 | RETURN @result; 16 | END 17 | GO -------------------------------------------------------------------------------- /src/T-SQL/Scalar UDFs/sudf_5_morEveRatio.sql: -------------------------------------------------------------------------------- 1 | --What is the ratio between the number of items sold over the internet in the morning (8 to 9am) to the number of 2 | --items sold in the evening (7 to 8pm) of customers with a specified number of dependents. 3 | 4 | create or alter function morningToEveRatio(@dep int) 5 | returns float 6 | as 7 | begin 8 | declare @morningSale int; 9 | declare @eveningSale int; 10 | declare @ratio float; 11 | set @morningSale = (select count(*) 12 | from web_sales_history, time_dim, customer_demographics 13 | where ws_sold_time_sk = t_time_sk and ws_bill_customer_sk = cd_demo_sk 14 | and t_hour>=8 and t_hour<=9 15 | and cd_dep_count=@dep); 16 | 17 | set @eveningSale = (select count(*) 18 | from web_sales_history, time_dim, customer_demographics 19 | where ws_sold_time_sk = t_time_sk and ws_bill_customer_sk = cd_demo_sk 20 | and t_hour>=19 and t_hour<=20 21 | and cd_dep_count=@dep); 22 | 23 | set @ratio = cast (@morningSale as float) / cast (@eveningSale as float); 24 | return @ratio; 25 | end 26 | go 27 | 28 | --invocation query 29 | select t.depCount, dbo.morningToEveRatio(t.depCount) from 30 | (select distinct cd_dep_count as depCount from customer_demographics)t; -------------------------------------------------------------------------------- /src/T-SQL/Scalar UDFs/sudf_6_totalDiscount.sql: -------------------------------------------------------------------------------- 1 | --Compute the total discount on web sales of items from a given manufacturer for 2 | --sales whose discount exceeded 30% over the average discount of items from that manufacturer. 3 | 4 | create or alter function totalDiscount (@manufacture_id int) 5 | returns decimal(15,2) 6 | as 7 | begin 8 | declare @avg decimal(15,2); 9 | declare @s decimal(15, 2); 10 | set @avg = (select avg(ws_ext_discount_amt) from web_sales_history, item 11 | where ws_item_sk = i_item_sk and i_manufact_id = @manufacture_id); 12 | 13 | set @s = (select sum(ws_ext_discount_amt) from web_sales_history, item 14 | where ws_item_sk = i_item_sk and i_manufact_id = @manufacture_id and 15 | ws_ext_discount_amt>1.3*@avg); 16 | return @s; 17 | end 18 | go 19 | 20 | select distinct i_manufact_id, dbo.totalDiscount(i_manufact_id) as totalDisc from item; -------------------------------------------------------------------------------- /src/T-SQL/Scalar UDFs/sudf_7_profitableManager.sql: -------------------------------------------------------------------------------- 1 | --Were the stores run by the given manager profitable in the given year? 2 | 3 | create or alter function profitableManager(@manager varchar(40), @year int) 4 | returns int as 5 | begin 6 | declare @netProfit decimal(15,2); 7 | set @netProfit = (select sum(ss_net_profit) 8 | from store, store_sales_history, date_dim 9 | where ss_sold_date_sk = d_date_sk 10 | and d_year=@year 11 | and s_manager = @manager 12 | and s_store_sk = ss_store_sk); 13 | if(@netProfit>0) 14 | return 1; 15 | return 0; 16 | end 17 | go 18 | 19 | --invocation query 20 | select s_manager from store where dbo.profitableManager(s_manager, 2001)<=0; 21 | go -------------------------------------------------------------------------------- /src/T-SQL/Scalar UDFs/sudf_8_maxRetClass.sql: -------------------------------------------------------------------------------- 1 | --Class of items that is returned the most on catalog in the curent cycle (non-history). 2 | 3 | create or alter function maxReturnClass() 4 | returns char (50) as 5 | begin 6 | declare c1 cursor static for 7 | (select i_class, count(i_class) as cnt 8 | from catalog_returns, item 9 | where i_item_sk = cr_item_sk 10 | group by i_class 11 | ); 12 | declare @count int; 13 | declare @class char(50); 14 | declare @maxClass char(50); 15 | declare @maxReturn int =0; 16 | open c1; 17 | fetch next from c1 into @class, @count; 18 | while(@@fetch_status=0) 19 | begin 20 | if(@count>@maxReturn) 21 | begin 22 | set @maxReturn = @Count; 23 | set @maxclass = @class; 24 | end 25 | fetch next from c1 into @class, @count; 26 | end 27 | close c1; 28 | deallocate c1; 29 | return @maxClass; 30 | end 31 | go -------------------------------------------------------------------------------- /src/T-SQL/Scalar UDFs/sudf_9a_correlation_wealthShipCost_Catalog.sql: -------------------------------------------------------------------------------- 1 | -- see if there is correlation betwen paying high shipping costs through catalog and 2 | --having a large number of high income inhabitants (at the state level)) 3 | 4 | create or alter function wealth_shipCostCorrelation_cat() 5 | returns varchar(40) 6 | as 7 | begin 8 | declare @numStates int =0; 9 | 10 | set @numStates = (select count(*) from 11 | ( select ca_state from 12 | (select top 5 ca_state, sum(cs_ext_ship_cost) as sm 13 | from catalog_sales_history, customer_address 14 | where cs_bill_customer_sk = ca_address_sk and ca_state is not NULL 15 | group by ca_state 16 | order by sm desc)t1 17 | 18 | INTERSECT 19 | 20 | select ca_state from --states wth largest numeber high income people 21 | (select top 5 ca_state, count(*) as cnt 22 | from customer, household_demographics, customer_address 23 | where c_current_hdemo_sk = hd_demo_sk and c_current_addr_sk = ca_address_sk and hd_income_band_sk>=15 and ca_state is not NULL 24 | group by ca_state 25 | order by cnt desc)t2 26 | )t3 ) 27 | 28 | if(@numStates>=4) 29 | return 'hihgly correlated'; 30 | if(@numStates>=2 and @numStates<=3) 31 | return 'somewhat correlated'; 32 | if(@numStates>=0 and @numStates<=1) 33 | return 'no correlation'; 34 | return 'error'; 35 | end -------------------------------------------------------------------------------- /src/T-SQL/Scalar UDFs/sudf_9b_correlation_wealthShipCost_web.sql: -------------------------------------------------------------------------------- 1 | -- see if there is correlation betwen paying high shipping costs through web and 2 | --having a large number of high income inhabitants (at the state level)) 3 | 4 | create or alter function wealth_shipCostCorrelation_web() 5 | returns varchar(40) 6 | as 7 | begin 8 | declare @numStates int =0; 9 | 10 | set @numStates = (select count(*) from 11 | ( select ca_state from 12 | (select top 5 ca_state, sum(ws_ext_ship_cost) as sm 13 | from web_sales_history, customer_address 14 | where ws_bill_customer_sk = ca_address_sk and ca_state is not NULL 15 | group by ca_state 16 | order by sm desc)t1 17 | 18 | INTERSECT 19 | 20 | select ca_state from --states with largest number of high income people 21 | (select top 5 ca_state, count(*) as cnt 22 | from customer, household_demographics, customer_address 23 | where c_current_hdemo_sk = hd_demo_sk and c_current_addr_sk = ca_address_sk and hd_income_band_sk>=15 and ca_state is not NULL 24 | group by ca_state 25 | order by cnt desc)t2 26 | )t3 ) 27 | 28 | if(@numStates>=4) 29 | return 'highly correlated'; 30 | if(@numStates>=2 and @numStates<=3) 31 | return 'somewhat correlated'; 32 | if(@numStates>=0 and @numStates<=1) 33 | return 'no correlation'; 34 | return 'error'; 35 | end 36 | go 37 | 38 | 39 | 40 | -------------------------------------------------------------------------------- /src/T-SQL/Stored Procedures/proc10_remove_item.sql: -------------------------------------------------------------------------------- 1 | CREATE PROCEDURE removeItem (@item_sk int) 2 | AS 3 | BEGIN 4 | DELETE from item where i_item_sk = @item_sk; 5 | END -------------------------------------------------------------------------------- /src/T-SQL/Stored Procedures/proc11_repeatedShoppers.sql: -------------------------------------------------------------------------------- 1 | --people who shopped in 5 diffrent months in a given year from store 2 | --make it a function maybe 3 | 4 | create or alter procedure repeatedShoppers (@year int) 5 | as 6 | begin 7 | set nocount on; 8 | 9 | select ss_customer_sk, count(*) 10 | from 11 | (select distinct ss_customer_sk, d_moy 12 | from store_sales_history, date_dim 13 | where ss_sold_date_sk = d_date_sk 14 | and d_year = 2001 15 | and ss_customer_sk is not NULL 16 | )t 17 | group by ss_customer_sk 18 | having count(*)>=5 19 | order by count(*) desc 20 | 21 | end 22 | go 23 | -------------------------------------------------------------------------------- /src/T-SQL/Stored Procedures/proc12_returnReason_highlyEducated.sql: -------------------------------------------------------------------------------- 1 | create or alter procedure returnReason_highEducated 2 | as 3 | begin 4 | set nocount on; 5 | 6 | select r_reason_desc, count(*) as cnt 7 | from store_returns_history, customer_demographics, reason 8 | where sr_customer_sk = cd_demo_sk and sr_reason_sk = r_reason_sk and cd_education_status = 'Advanced Degree' 9 | group by r_reason_desc 10 | order by cnt desc; 11 | end -------------------------------------------------------------------------------- /src/T-SQL/Stored Procedures/proc13_returnReason_lessEducated.sql: -------------------------------------------------------------------------------- 1 | create or alter procedure returnReason_lessEducated 2 | as 3 | begin 4 | set nocount on; 5 | 6 | select r_reason_desc, count(*) as cnt 7 | from store_returns_history, customer_demographics, reason 8 | where sr_customer_sk = cd_demo_sk and sr_reason_sk = r_reason_sk and cd_education_status = 'Primary' 9 | group by r_reason_desc 10 | order by cnt desc; 11 | end -------------------------------------------------------------------------------- /src/T-SQL/Stored Procedures/proc14_salePerBrandCatalog.sql: -------------------------------------------------------------------------------- 1 | --Report the total extended sales price per item brand of a specific manufacturer for all catalog sales in a specific month 2 | --of the year. 3 | CREATE PROCEDURE salePerBrandCatalog (@year int, @month int, @manufacture int) 4 | AS 5 | BEGIN 6 | SET NOCOUNT ON; 7 | 8 | select i_brand, sum(cs_ext_sales_price) as totalSale 9 | from catalog_sales_history, item, date_dim 10 | where i_item_sk = cs_item_sk 11 | and i_manufact_id = @manufacture 12 | and cs_sold_date_sk = d_date_sk 13 | and d_year = @year 14 | and d_moy = @month 15 | group by i_brand 16 | END -------------------------------------------------------------------------------- /src/T-SQL/Stored Procedures/proc15_salePerBrandStore.sql: -------------------------------------------------------------------------------- 1 | --Report the total extended sales price per item brand of a specific manufacturer for all store sales in a specific month 2 | --of the year. 3 | CREATE PROCEDURE salePerBrandStore (@year int, @month int, @manufacture int) 4 | AS 5 | BEGIN 6 | SET NOCOUNT ON; 7 | 8 | select i_brand, sum(ss_ext_sales_price) as totalSale 9 | from store_sales_history, item, date_dim 10 | where i_item_sk = ss_item_sk 11 | and i_manufact_id = @manufacture 12 | and ss_sold_date_sk = d_date_sk 13 | and d_year = @year 14 | and d_moy = @month 15 | group by i_brand 16 | END -------------------------------------------------------------------------------- /src/T-SQL/Stored Procedures/proc16_salePerBrandWeb.sql: -------------------------------------------------------------------------------- 1 | --Report the total extended sales price per item brand of a specific manufacturer for all web sales in a specific month 2 | --of the year. 3 | CREATE PROCEDURE salePerBrandWeb (@year int, @month int, @manufacture int) 4 | AS 5 | BEGIN 6 | SET NOCOUNT ON; 7 | 8 | select i_brand, sum(ws_ext_sales_price) as totalSale 9 | from web_sales_history, item, date_dim 10 | where i_item_sk = ws_item_sk 11 | and i_manufact_id = @manufacture 12 | and ws_sold_date_sk = d_date_sk 13 | and d_year = @year 14 | and d_moy = @month 15 | group by i_brand 16 | END -------------------------------------------------------------------------------- /src/T-SQL/Stored Procedures/proc17_saleShoppers.sql: -------------------------------------------------------------------------------- 1 | --information on customers who purchased items from catalog that were on sale during a particular time 2 | CREATE PROCEDURE saleShoppers 3 | AS 4 | BEGIN 5 | set nocount on; 6 | 7 | select cs_bill_customer_sk as customer_sk, 8 | c_first_name, c_last_name, c_email_address, c_birth_year, 9 | cs_item_sk, d1.d_date as sold_date, 10 | d2.d_date as promo_strt_date, d3.d_date as promo_end_date, 11 | cs_promo_sk 12 | from catalog_sales_history, promotion, date_dim d1, date_dim d2, date_dim d3, customer 13 | where p_promo_sk = cs_promo_sk 14 | and cs_sold_date_sk = d1.d_date_sk 15 | and p_start_date_sk = d2.d_date_sk 16 | and p_end_date_sk = d3.d_date_sk 17 | and d1.d_date>=d2.d_date 18 | and d1.d_date<=d3.d_date 19 | and cs_bill_customer_sk = c_customer_sk 20 | 21 | END -------------------------------------------------------------------------------- /src/T-SQL/Stored Procedures/proc18_updateItemPrice.sql: -------------------------------------------------------------------------------- 1 | CREATE PROCEDURE updateItemPrice (@itemSk int, @newPrice decimal(7, 2)) 2 | AS 3 | BEGIN 4 | UPDATE item set i_current_price = @newPrice 5 | where i_item_sk = @itemSk 6 | and @newPrice < 3*i_wholesale_cost; 7 | END -------------------------------------------------------------------------------- /src/T-SQL/Stored Procedures/proc19_updateWebUrl.sql: -------------------------------------------------------------------------------- 1 | CREATE or alter PROCEDURE updateWebURL(@oldUrl varchar(100), @newUrl varchar(100)) 2 | AS 3 | BEGIN 4 | set nocount on; 5 | 6 | UPDATE web_page 7 | set wp_url = @newUrl 8 | where wp_url = @oldUrl; 9 | END 10 | go 11 | 12 | --execution query 13 | exec updateWebURL 'http://www.bar.com', 'http://www.foo.com' 14 | go -------------------------------------------------------------------------------- /src/T-SQL/Stored Procedures/proc1_custDemoSaleInfo.sql: -------------------------------------------------------------------------------- 1 | --Calculate the average sales quantity, average sales price, average wholesale cost, total wholesale cost for store 2 | --sales of different customer types (based on marital status and gender) from the given state. 3 | 4 | CREATE PROCEDURE customerDemographicSaleInfo (@state char(2)) 5 | AS 6 | BEGIN 7 | 8 | select ca_state, cd_gender, cd_marital_status, avg(ss_quantity) as avg_qty, avg(ss_sales_price) avg_sale, 9 | avg(ss_ext_wholesale_cost) as avg_wholsesale, sum(ss_ext_wholesale_cost) as sum_wholesale 10 | from store_sales_history, customer_demographics, customer, customer_address 11 | where ss_cdemo_sk = cd_demo_sk 12 | and c_customer_sk = ss_customer_sk 13 | and c_current_cdemo_sk = ca_address_sk 14 | and ca_state = '@state' 15 | group by ca_state, cd_gender, cd_marital_status 16 | END -------------------------------------------------------------------------------- /src/T-SQL/Stored Procedures/proc20_warehouse_addressGet.sql: -------------------------------------------------------------------------------- 1 | CREATE PROCEDURE warehouseAddress_Get (@warehouseId char(16)) 2 | AS 3 | BEGIN 4 | select w_warehouse_name, w_street_number, w_street_name, w_suite_number, w_city, w_county, w_state, w_zip, w_country 5 | FROM warehouse 6 | where w_warehouse_id = @warehouseId 7 | END 8 | GO 9 | -------------------------------------------------------------------------------- /src/T-SQL/Stored Procedures/proc21_activatePromoCat.sql: -------------------------------------------------------------------------------- 1 | create or alter procedure activatePromoCat 2 | as 3 | begin 4 | declare @promo_sk int; 5 | declare c1 cursor static for (select promo_sk from dbo.bestPromosCatalog()); 6 | open c1; 7 | fetch next from c1 into @promo_sk; 8 | while(@@FETCH_STATUS=0) 9 | begin 10 | update promotion set p_end_date_sk = 10000000, p_discount_active='Y' 11 | where p_promo_sk = @promo_sk; 12 | 13 | fetch next from c1 into @promo_sk; 14 | end 15 | close c1; 16 | deallocate c1; 17 | end 18 | go -------------------------------------------------------------------------------- /src/T-SQL/Stored Procedures/proc22_activatePromoStore.sql: -------------------------------------------------------------------------------- 1 | create or alter procedure activatePromoStore 2 | as 3 | begin 4 | declare @promo_sk int; 5 | declare c1 cursor static for (select promo_sk from dbo.bestPromoStore()); 6 | open c1; 7 | fetch next from c1 into @promo_sk; 8 | while(@@FETCH_STATUS=0) 9 | begin 10 | update promotion set p_end_date_sk = 10000000, p_discount_active='Y' 11 | where p_promo_sk = @promo_sk; 12 | 13 | fetch next from c1 into @promo_sk; 14 | end 15 | close c1; 16 | deallocate c1; 17 | end 18 | go -------------------------------------------------------------------------------- /src/T-SQL/Stored Procedures/proc23_activatePromoWeb.sql: -------------------------------------------------------------------------------- 1 | create or alter procedure activatePromoWeb 2 | as 3 | begin 4 | declare @promo_sk int; 5 | declare c1 cursor static for (select promo_sk from dbo.bestPromosWeb()); 6 | open c1; 7 | fetch next from c1 into @promo_sk; 8 | while(@@FETCH_STATUS=0) 9 | begin 10 | update promotion set p_end_date_sk = 10000000, p_discount_active='Y' 11 | where p_promo_sk = @promo_sk; 12 | 13 | fetch next from c1 into @promo_sk; 14 | end 15 | CLOSE C1; 16 | DEALLOCATE C1; 17 | end 18 | go -------------------------------------------------------------------------------- /src/T-SQL/Stored Procedures/proc24_CreateRandmString.sql: -------------------------------------------------------------------------------- 1 | CREATE or alter PROCEDURE CreateRandomString 2 | @randomString VARCHAR(16) OUTPUT 3 | AS BEGIN 4 | SET NOCOUNT ON; 5 | 6 | DECLARE @stringLength INT =16; 7 | DECLARE @chars VARCHAR(200) = 'ABCDEFGHIJKLMNOPQRSTUVWXYZ'; 8 | SET @randomString = ''; 9 | 10 | WHILE LEN(@randomString) < @stringLength 11 | BEGIN 12 | SET @randomString = @randomString + dbo.genRandomChar(@chars, RAND()); 13 | END 14 | END 15 | go 16 | 17 | --ivocation query 18 | declare @randomString VARCHAR(16); 19 | EXEC [dbo].[CreateRandomString] @randomString OUTPUT; 20 | SELECT @randomString AS [Random String]; 21 | go 22 | 23 | 24 | 25 | -------------------------------------------------------------------------------- /src/T-SQL/Stored Procedures/proc25_delCatPage.sql: -------------------------------------------------------------------------------- 1 | create or alter procedure deleteCatalogPage(@delContent varchar(20), @updateContent varchar(20), @updateDept varchar(40)) 2 | as 3 | begin 4 | if(@delContent!='') 5 | begin 6 | select cp_catalog_number as deletedCat, cp_catalog_page_number as deletedPgNum 7 | from catalog_page 8 | where cp_description like '%'+@delContent+'%'; 9 | 10 | delete from catalog_page where cp_description like '%'+@delContent+'%'; 11 | end 12 | 13 | if(@updateContent!='') 14 | update catalog_page set cp_department = @updateDept where cp_description like '%'+@updateDept+'%'; 15 | end 16 | go 17 | 18 | --execution query 19 | exec dbo.deleteCatalogPage 'weapon', 'patient', 'Medical' 20 | go -------------------------------------------------------------------------------- /src/T-SQL/Stored Procedures/proc26_getReturnReason.sql: -------------------------------------------------------------------------------- 1 | use tpcds_10gb; 2 | go 3 | --does look rather weird. Change logic. 4 | create procedure getReturnReason 5 | @reason_sk int, 6 | @reason_id nvarchar(16) 7 | as 8 | begin 9 | set nocount on 10 | 11 | if(@reason_sk = null and @reason_id = null) 12 | begin 13 | raiserror('Invalid arguments', 16, 1) 14 | end 15 | 16 | declare @curDate date = GetDate(); 17 | declare @day int = DAY(@curDate); 18 | declare @month int = MONTH(@curDate); 19 | declare @year int = YEAR(@curDate); 20 | 21 | select cr_reason_sk, r_reason_desc 22 | from catalog_returns, date_dim, reason 23 | where cr_returned_date_sk = d_date_sk 24 | and r_reason_sk = cr_reason_sk 25 | and d_moy <= @month and d_moy >= @month-5; 26 | end 27 | 28 | select * from reason 29 | -------------------------------------------------------------------------------- /src/T-SQL/Stored Procedures/proc27_getStoreByManager.sql: -------------------------------------------------------------------------------- 1 | create or alter procedure getStoreByManager(@manager varchar(40)) 2 | as 3 | begin 4 | if not exists (select * from store where s_manager= @manager) 5 | begin 6 | RAISERROR('No stores operated by this manager', 10, 16); 7 | end 8 | else 9 | select s_street_number, s_street_name, s_street_type, s_suite_number, s_city, s_county, s_state,s_zip, s_country 10 | from store 11 | where s_manager = @manager; 12 | end 13 | -------------------------------------------------------------------------------- /src/T-SQL/Stored Procedures/proc28_insertCallCenter.sql: -------------------------------------------------------------------------------- 1 | CREATE PROCEDURE InsertCallCenter (@strt_date date, @end_date date, @cc_closed_date int, @open_date int , @cc_name varchar(50), 2 | @sk int, @id char(16), @class varchar(50), @numEmpl int, @size int, @hrs char(20), 3 | @manager varchar(40), @mkt_id int, @mkt_cls char(50), @mkt_desc varchar(100), 4 | @Mktmanager varchar(40), @div int, @divName varchar(50), @company int, @company_name char(50), 5 | @st_num char(10), stName varchar(60), stType char(15), @cc_suite char(10), 6 | @city varchar(60), @county varchar(30), @state char(2), @zip char(10), 7 | @country varchar(20), @offset decimal(5,2), @taxPercent decimal(5,2)) 8 | AS 9 | BEGIN 10 | set nocount on; 11 | if not exists (select * from call_center where cc_call_center_sk = @sk) 12 | insert into call_center values (@strt_date, @end_date, @cc_closed_date, @open_date, @cc_name, @sk, @id, @class, @numEmpl, @size, @hrs, 13 | @manager, @mkt_id, @mkt_cls, @mkt_desc, @Mktmanager, @div, @divName, @company, 14 | @company_name, @st_num, stName, stType, @cc_suite, @cit, @county, @state, @zip, @country, 15 | @offset, @taxPercent) 16 | END -------------------------------------------------------------------------------- /src/T-SQL/Stored Procedures/proc29_insertNewShipCarrier.sql: -------------------------------------------------------------------------------- 1 | create or alter procedure newShippingCarrier(@type char(30), @code char(10), @name char(20), 2 | @contract char(20)) 3 | as 4 | begin 5 | set nocount on; 6 | 7 | declare @randomString char(16); 8 | declare @sk int; 9 | declare @id char(16); 10 | 11 | set @sk = (select max(sm_ship_mode_sk)+1 from ship_mode ); 12 | 13 | EXEC dbo.CreateRandomString @randomString OUTPUT; 14 | set @id = @randomString; 15 | 16 | insert into ship_mode (sm_ship_mode_sk, sm_ship_mode_id, sm_type, sm_code, sm_carrier, sm_contract) 17 | values (@sk, @id, @type, @code, @name, @contract); 18 | 19 | end 20 | 21 | --calling query 22 | exec dbo.newShippingCarrier 'FORTNIGHT', 'SEA', 'SHIPCo', '83hdjk0hf8j' 23 | go 24 | 25 | -------------------------------------------------------------------------------- /src/T-SQL/Stored Procedures/proc2_excessReturn_web.sql: -------------------------------------------------------------------------------- 1 | CREATE PROCEDURE excessReturn_web 2 | AS 3 | BEGIN 4 | set nocount on; 5 | 6 | WITH ReturnTable 7 | AS (SELECT wr_returning_customer_sk, 8 | ca_state, 9 | Sum(wr_return_amt) as returnAmt 10 | FROM web_returns_history, 11 | customer_address, 12 | date_dim 13 | WHERE wr_returned_date_sk = d_date_sk 14 | and wr_returning_addr_sk = ca_address_sk 15 | AND d_year = 2001 16 | GROUP BY wr_returning_customer_sk, 17 | ca_state) 18 | SELECT c_customer_id, c_salutation, c_first_name, c_last_name, c_email_address, c_birth_year, c_birth_country 19 | FROM ReturnTable tr1, 20 | customer_address ca1, 21 | customer 22 | WHERE tr1.returnAmt > (SELECT Avg(returnAmt) * 1.2 23 | FROM ReturnTable tr2 24 | WHERE tr1.ca_state = tr2.ca_state) 25 | AND ca_address_sk = c_current_addr_sk 26 | AND tr1.wr_returning_customer_sk = c_customer_sk 27 | AND ca1.ca_state = 'TX' 28 | END -------------------------------------------------------------------------------- /src/T-SQL/Stored Procedures/proc30_lossByEdcated-Risky.sql: -------------------------------------------------------------------------------- 1 | --Total loss incurred on each channel by credit risky, hihgly educated men with non-zero dependents 2 | 3 | create or alter procedure lossByEducated_risky 4 | as 5 | begin 6 | declare @web_loss decimal(15,2); 7 | declare @cat_loss decimal(15,2); 8 | declare @total_loss decimal(15,2); 9 | 10 | select @web_loss = sum(ws_net_profit) 11 | from web_sales_history 12 | where ws_bill_cdemo_sk in 13 | (select cd_demo_sk from customer_demographics where cd_gender='M' and cd_education_status = 'Advanced Degree' 14 | and cd_dep_count>0 and cd_credit_rating = 'High Risk') 15 | and ws_net_profit<0; 16 | 17 | select @cat_loss = sum(cs_net_profit) 18 | from catalog_sales_history 19 | where cs_bill_cdemo_sk in 20 | (select cd_demo_sk from customer_demographics where cd_gender='M' and cd_education_status = 'Advanced Degree' 21 | and cd_dep_count>0 and cd_credit_rating = 'High Risk') 22 | and cs_net_profit<0; 23 | 24 | select @total_loss = @web_loss + @cat_loss; 25 | print(@total_loss); 26 | end -------------------------------------------------------------------------------- /src/T-SQL/Stored Procedures/proc31_maxSaleElectronicsMonth.sql: -------------------------------------------------------------------------------- 1 | --which months registered the highest store sale of electronics for a given 3 year period. 2 | 3 | --which months registered the highest sale of electronics for 3 year period startig at the given year. 4 | 5 | create or alter procedure maxSaleElectronicsMonth(@year int) 6 | as 7 | begin 8 | declare @month1 int, @month2 int, @month3 int; 9 | 10 | set @month1 = (select top 1 d_moy 11 | from store_sales_history, item, date_dim 12 | where ss_item_sk = i_item_sk and ss_sold_date_sk=d_date_sk and d_year = @year and i_category='Electronics' 13 | group by d_moy 14 | order by count(*) desc); 15 | 16 | set @month2= (select top 1 d_moy 17 | from store_sales_history, item, date_dim 18 | where ss_item_sk = i_item_sk and ss_sold_date_sk=d_date_sk and d_year = @year+1 and i_category='Electronics' 19 | group by d_moy 20 | order by count(*) desc); 21 | 22 | set @month3 = (select top 1 d_moy 23 | from store_sales_history, item, date_dim 24 | where ss_item_sk = i_item_sk and ss_sold_date_sk=d_date_sk and d_year = @year+2 and i_category='Electronics' 25 | group by d_moy 26 | order by count(*) desc); 27 | 28 | select @month1 as year1 , @month2 as year2 , @month3 as year3; 29 | end -------------------------------------------------------------------------------- /src/T-SQL/Stored Procedures/proc32_maxSaleJewelryMonth.sql: -------------------------------------------------------------------------------- 1 | --which months registered the highest sale of jewelry for 3 year period startig at the given year. 2 | 3 | create or alter procedure maxSaleJewelryMonth(@year int) 4 | as 5 | begin 6 | declare @month1 int, @month2 int, @month3 int; 7 | set @month1 = (select top 1 d_moy 8 | from store_sales_history, item, date_dim 9 | where ss_item_sk = i_item_sk and ss_sold_date_sk=d_date_sk and d_year = @year and i_category='jewelry' 10 | group by d_moy 11 | order by count(*) desc); 12 | 13 | set @month2= (select top 1 d_moy 14 | from store_sales_history, item, date_dim 15 | where ss_item_sk = i_item_sk and ss_sold_date_sk=d_date_sk and d_year = @year+1 and i_category='jewelry' 16 | group by d_moy 17 | order by count(*) desc); 18 | 19 | set @month3 = (select top 1 d_moy 20 | from store_sales_history, item, date_dim 21 | where ss_item_sk = i_item_sk and ss_sold_date_sk=d_date_sk and d_year = @year+2 and i_category='jewelry' 22 | group by d_moy 23 | order by count(*) desc); 24 | 25 | select @month1 as year1 , @month2 as year2 , @month3 as year3 26 | end 27 | -------------------------------------------------------------------------------- /src/T-SQL/Stored Procedures/proc33_newCatalogPage.sql: -------------------------------------------------------------------------------- 1 | create or alter procedure newCatalogPage(@strtDate int, @endDate int, @dept varchar(50), @catNumber int, 2 | @pgNum int, @desc varchar(100), @typevarchar varchar(100)) 3 | as 4 | begin 5 | set nocount on; 6 | 7 | declare @randomString char(16); 8 | declare @sk int; 9 | declare @id char(16); 10 | 11 | set @sk = (select max(cp_catalog_page_sk)+1 from catalog_page); 12 | 13 | EXEC dbo.CreateRandomString @randomString OUTPUT; 14 | set @id = @randomString; 15 | insert into catalog_page (cp_catalog_page_sk, cp_catalog_page_id, cp_start_date_sk, cp_end_date_sk, 16 | cp_department, cp_catalog_number, cp_catalog_page_number, cp_description, cp_type) 17 | values (@sk, @id, @strtDate, @endDate, @dept, @catNumber, @pgNum, @desc, @typevarchar); 18 | end -------------------------------------------------------------------------------- /src/T-SQL/Stored Procedures/proc34_newPromotion.sql: -------------------------------------------------------------------------------- 1 | create procedure new_promotion(@item_sk int, @start_date int, @end_date int, @cost decimal(15, 2)) 2 | as 3 | begin 4 | set nocount on; 5 | declare @newSk int, @maxSk int; 6 | set @maxSk = (select max(p_promo_sk) from promotion); 7 | 8 | set @newSk = @maxSk+1; 9 | 10 | insert into promotion(p_promo_sk, p_start_date_sk, p_end_date_sk, p_item_sk, p_cost, p_discount_active) 11 | values (@newSk, @start_date, @end_date, @item_sk, @cost, 'Y'); 12 | end 13 | -------------------------------------------------------------------------------- /src/T-SQL/Stored Procedures/proc35_newStore.sql: -------------------------------------------------------------------------------- 1 | create procedure newStore(@store_sk int, @manager varchar(40)) 2 | as 3 | begin 4 | if not exists (select * from store where s_store_sk=@store_sk) 5 | insert into store (s_store_sk, s_store_id, s_manager) values (@store_sk, DEFAULT, @manager); 6 | else 7 | update store set s_manager = @manager where s_store_sk = @store_sk; 8 | end 9 | 10 | go -------------------------------------------------------------------------------- /src/T-SQL/Stored Procedures/proc36_newWarehouse.sql: -------------------------------------------------------------------------------- 1 | --add a new warehouse to the database: 2 | create or alter procedure newWarehouse(@name varchar(20), @sqFt int, @streetNo char(10), @stName varchar(60), 3 | @suite char(10),@city varchar(60), @county varchar(30), @state char(2), 4 | @zip char(10), @country varchar(20)) 5 | as 6 | begin 7 | declare @randomString char(16); 8 | declare @sk int; 9 | declare @id char(16); 10 | set @sk = (select max(w_warehouse_sk)+1 from warehouse ); 11 | 12 | EXEC dbo.CreateRandomString @randomString OUTPUT; 13 | set @id = @randomString; 14 | insert into warehouse (w_warehouse_sk, w_warehouse_id, w_warehouse_name, w_warehouse_sq_ft, w_street_number, 15 | w_street_name, w_suite_number, w_city, w_county, w_state, w_zip, w_country) 16 | values (@sk, @id, @name, @sqFt, @streetNo, @stName, @suite, @city, @county, @state, @zip, @country); 17 | 18 | end -------------------------------------------------------------------------------- /src/T-SQL/Stored Procedures/proc37_procesStoreReturn.sql: -------------------------------------------------------------------------------- 1 | --new return request 2 | 3 | create procedure processReturn_store 4 | (@item_sk int, @cust_sk int, @reason_sk int, @ticketNum int, @returnQty int, @returnReason char(100)) 5 | as 6 | begin 7 | declare @curDate date = GETDATE(); 8 | declare @dateSk int; 9 | set @dateSk = (select d_date_sk from date_dim where d_date = @curDate); 10 | insert into store_returns (sr_returned_date_sk, sr_item_sk, sr_customer_sk, sr_reason_sk, sr_ticket_number, sr_return_quantity) 11 | values (@dateSk, @item_sk, @cust_sk, @reason_sk, @ticketNum, @returnQty); 12 | if exists (select * from reason where r_reason_sk=@reason_sk) 13 | return; 14 | else 15 | insert into reason (r_reason_sk, r_reason_desc) values (@reason_sk, @returnReason); 16 | end 17 | -------------------------------------------------------------------------------- /src/T-SQL/Stored Procedures/proc38_removeObj.sql: -------------------------------------------------------------------------------- 1 | CREATE or ALTER PROCEDURE RemoveObject( 2 | @objName nvarchar(max), 3 | @newName NVARCHAR(MAX)=NULL OUTPUT, 4 | @IfExists int = 0) 5 | AS 6 | BEGIN 7 | DECLARE @ObjectId INT; 8 | SELECT @ObjectId = OBJECT_ID(@objName); 9 | 10 | IF(@ObjectId IS NULL) 11 | BEGIN 12 | IF(@IfExists = 1) RETURN; 13 | RAISERROR('%s does not exist!',16,10,@objName); 14 | END; 15 | 16 | EXEC dbo.RenameObjectUsingObjectId @ObjectId, @NewName = @NewName OUTPUT; 17 | END; 18 | GO -------------------------------------------------------------------------------- /src/T-SQL/Stored Procedures/proc39_removeObjIfExists.sql: -------------------------------------------------------------------------------- 1 | CREATE PROCEDURE RemoveObjectIfExists( 2 | @ObjectName NVARCHAR(MAX), 3 | @NewName NVARCHAR(MAX) = NULL OUTPUT 4 | ) 5 | AS 6 | BEGIN 7 | set nocount on; 8 | if exists (select * from sys.objects where name = @ObjectName) 9 | EXEC dbo.RemoveObject @ObjectName = @ObjectName, @NewName = @NewName OUT, @IfExists = 1; 10 | END; 11 | GO 12 | -------------------------------------------------------------------------------- /src/T-SQL/Stored Procedures/proc3_excessReturnCustInfo.sql: -------------------------------------------------------------------------------- 1 | CREATE PROCEDURE getExcessReturnCustInfo 2 | AS 3 | BEGIN 4 | WITH totalReturn 5 | AS (SELECT sr_customer_sk, 6 | sr_store_sk, 7 | Sum(sr_return_amt) as returnAmt 8 | FROM store_returns_history, 9 | date_dim 10 | WHERE sr_returned_date_sk = d_date_sk 11 | AND d_year = 2001 12 | GROUP BY sr_customer_sk, 13 | sr_store_sk) 14 | SELECT distinct c_customer_id, c_email_address, cd_gender, cd_credit_rating 15 | FROM totalReturn tr1, 16 | store, 17 | customer, 18 | customer_demographics 19 | WHERE tr1.returnAmt > (SELECT Avg(returnAmt) * 1.2 20 | FROM totalReturn tr2 21 | WHERE tr1.sr_store_sk = tr2.sr_store_sk) 22 | AND s_store_sk = tr1.sr_store_sk 23 | AND tr1.sr_customer_sk = c_customer_sk 24 | AND c_current_cdemo_sk = cd_demo_sk 25 | 26 | end 27 | 28 | 29 | 30 | 31 | 32 | 33 | 34 | -------------------------------------------------------------------------------- /src/T-SQL/Stored Procedures/proc40_renameObj.sql: -------------------------------------------------------------------------------- 1 | CREATE PROCEDURE RenameObject( 2 | @SchemaName NVARCHAR(MAX), 3 | @ObjectName NVARCHAR(MAX), 4 | @NewName NVARCHAR(MAX) = NULL OUTPUT 5 | ) 6 | AS 7 | BEGIN 8 | SET @NewName='newName123'; 9 | 10 | DECLARE @RenameCmd NVARCHAR(MAX); 11 | SET @RenameCmd = 'EXEC sp_rename ''' + 12 | @SchemaName + '.' + @ObjectName + ''', ''' + 13 | @NewName + ''';'; 14 | 15 | EXEC @RenameCmd; 16 | 17 | END; -------------------------------------------------------------------------------- /src/T-SQL/Stored Procedures/proc41_renameUsingObjId.sql: -------------------------------------------------------------------------------- 1 | CREATE PROCEDURE RenameObjectUsingObjectId( 2 | @ObjectId INT, 3 | @NewName NVARCHAR(MAX) = NULL OUTPUT 4 | ) 5 | AS 6 | BEGIN 7 | set nocount on; 8 | 9 | DECLARE @SchemaName NVARCHAR(MAX); 10 | DECLARE @ObjectName NVARCHAR(MAX); 11 | 12 | SELECT @SchemaName = QUOTENAME(OBJECT_SCHEMA_NAME(@ObjectId)), @ObjectName = QUOTENAME(OBJECT_NAME(@ObjectId)); 13 | 14 | EXEC dbo.RenameObject @SchemaName,@ObjectName, @NewName OUTPUT; 15 | END; 16 | GO -------------------------------------------------------------------------------- /src/T-SQL/Stored Procedures/proc42_totalInventoryDef.sql: -------------------------------------------------------------------------------- 1 | create procedure totalInventoryDefeciency 2 | as 3 | begin 4 | declare @webSales table(item_sk int, date_sk int, qty int) 5 | declare @catSales table(item_sk int, date_sk int, qty int) 6 | 7 | insert into @webSales 8 | select ws_item_sk, ws_sold_date_sk,sum(ws_quantity) 9 | from web_sales_history, date_dim 10 | where d_date_sk = ws_sold_date_sk and d_year>=2002 and d_year<=2003 11 | group by ws_sold_date_sk, ws_item_sk 12 | order by ws_item_sk 13 | 14 | insert into @catSales 15 | select cs_item_sk, cs_sold_date_sk,sum(cs_quantity) 16 | from catalog_sales_history, date_dim 17 | where d_date_sk = cs_sold_date_sk and d_year>=2002 and d_year<=2003 18 | group by cs_sold_date_sk, cs_item_sk 19 | order by cs_item_sk 20 | 21 | select d as date_sk, i as item_sk, sum(addi) as def_amount 22 | from 23 | (select t.date_sk as d, t.item_sk as i, -1*sum(qty) as addi 24 | from 25 | (select item_sk, date_sk, qty 26 | from @webSales ws 27 | 28 | UNION ALL 29 | 30 | select item_sk, date_sk, qty 31 | from @catSales cs)t 32 | group by item_sk, date_sk 33 | 34 | UNION ALL 35 | 36 | select inv_date_sk as d, inv_item_sk as i, sum(inv_quantity_on_hand) as addi 37 | from inventory_history, date_dim 38 | where inv_date_sk=d_date_sk and d_year>=2002 and d_year<=2003 39 | group by inv_date_sk, inv_item_sk)t2 40 | group by d, i 41 | having sum(addi)<0 42 | order by d, i 43 | end 44 | go -------------------------------------------------------------------------------- /src/T-SQL/Stored Procedures/proc43_DeleteCustomer.sql: -------------------------------------------------------------------------------- 1 | create or alter procedure deleteCustomer(@user_list UserList READONLY) 2 | as 3 | begin 4 | set nocount on; 5 | declare @sk int; 6 | 7 | declare custCur cursor static for (select UserSk from @user_list); 8 | open custCur; 9 | fetch next from custCur into @sk; 10 | while(@@fetch_status=0) 11 | begin 12 | delete from customer where c_customer_sk = @sk; 13 | fetch next from custCur into @sk; 14 | end 15 | close custCur; 16 | deallocate custCur; 17 | 18 | end 19 | go 20 | 21 | --invocation query 22 | CREATE TYPE UserList AS TABLE ( UserSk INT ); 23 | go 24 | 25 | DECLARE @UL UserList; 26 | INSERT @UL VALUES (5),(44),(72),(81),(126), (230), (467), (876), (1609), (3254), (78574), (435893); 27 | 28 | exec dbo.deleteCustomer @UL 29 | go -------------------------------------------------------------------------------- /src/T-SQL/Stored Procedures/proc44_cusWithIncomeInRange.sql: -------------------------------------------------------------------------------- 1 | --List all customers living in a specified city, in a given income band 2 | 3 | create or alter procedure cusWithIncomeInRange(@city varchar(60), @givenIb int) 4 | as 5 | begin 6 | declare @cust int, @ib int, @hhd int; 7 | declare c1 cursor for (select c_customer_sk from customer, customer_address 8 | where c_current_addr_sk=ca_address_sk and ca_city = @city); 9 | open c1; 10 | fetch next from c1 into @cust; 11 | while(@@FETCH_STATUS=0) 12 | begin 13 | set @hhd = (select c_current_hdemo_sk from customer where c_customer_sk = @cust); 14 | set @ib = (select hd_income_band_sk from household_demographics where hd_demo_sk=@hhd); 15 | if(@ib = @givenIb) 16 | print (@cust); 17 | fetch next from c1 into @cust; 18 | end 19 | end 20 | 21 | --invocation query 22 | exec dbo.cusWithIncomeInRange Hopewell, 2 -------------------------------------------------------------------------------- /src/T-SQL/Stored Procedures/proc45_moreOnlineThanStore.sql: -------------------------------------------------------------------------------- 1 | -- Customers who spend more money online than in stores 2 | 3 | create or alter procedure moreOnlineThanStore 4 | as 5 | begin 6 | declare @preferredChannel varchar(50); 7 | declare @cust int; 8 | declare c1 cursor static for (select c_customer_sk from customer); 9 | open c1; 10 | fetch next from c1 into @cust; 11 | while(@@FETCH_STATUS=0) 12 | begin 13 | set @preferredChannel = (select dbo.preferredChannel_wrtExpenditure(@cust)); 14 | if(@preferredChannel='catalog' or @preferredChannel='web') 15 | print(@cust); 16 | fetch next from c1 into @cust; 17 | end 18 | close c1; 19 | deallocate c1; 20 | end 21 | 22 | -------------------------------------------------------------------------------- /src/T-SQL/Stored Procedures/proc47_setPreferredCust.sql: -------------------------------------------------------------------------------- 1 | create or alter procedure setPreferredCustomers 2 | as 3 | begin 4 | declare @currentPref char(1); 5 | declare @cust int; 6 | 7 | create table #prefCust (cust_sk int); 8 | 9 | INSERT INTO #prefCust EXEC dbo.repeatedShoppers; 10 | 11 | declare c1 cursor static for (select cust_sk from #prefCust); 12 | open c1; 13 | fetch next from c1 into @cust; 14 | while(@@FETCH_STATUS=0) 15 | begin 16 | set @currentPref = (select c_preferred_cust_flag from customer where c_customer_sk=@cust); 17 | if(@currentPref='N') 18 | begin 19 | update customer set c_preferred_cust_flag='Y' where c_customer_sk=@cust; 20 | end 21 | fetch next from c1 into @cust; 22 | end 23 | close c1; 24 | deallocate c1; 25 | end -------------------------------------------------------------------------------- /src/T-SQL/Stored Procedures/proc48_unsatisfiedCustCat.sql: -------------------------------------------------------------------------------- 1 | --customers who after returning an order did not shop for atleast 6 months through the same channel(catalog). 2 | 3 | create or alter procedure unsatisfiedCustomersCat 4 | as 5 | begin 6 | declare @cust int; 7 | declare @retDate date, @minDate date; 8 | declare @custTable table (custSk int); 9 | declare c1 cursor static for 10 | (select cr_refunded_customer_sk, d_date from catalog_returns, date_dim 11 | where d_date_sk = cr_returned_date_sk and cr_refunded_customer_sk is not NULL); 12 | open c1; 13 | fetch next from c1 into @cust, @retDate; 14 | while(@@FETCH_STATUS=0) 15 | begin 16 | set @minDate = (select min(d_date) from catalog_sales, date_dim 17 | where cs_sold_date_sk=d_date_sk and cs_bill_customer_sk=@cust 18 | and d_date>@retDate); 19 | if(DATEDIFF(MONTH, @retDate, @minDate)>=6) 20 | begin 21 | insert into @custTable values (@cust); 22 | end 23 | fetch next from c1 into @cust, @retDate; 24 | end 25 | close c1; 26 | deallocate c1; 27 | select * from @custTable; 28 | end -------------------------------------------------------------------------------- /src/T-SQL/Stored Procedures/proc49_unsatisfiedCustsStore.sql: -------------------------------------------------------------------------------- 1 | --customers who after returning an order did not shop for atleast 6 months through the same channel(store). 2 | 3 | create or alter procedure unsatisfiedCustomersStore 4 | as 5 | begin 6 | declare @cust int; 7 | declare @retDate date, @minDate date; 8 | declare @custTable table (custSk int); 9 | declare c1 cursor static for 10 | (select sr_customer_sk, d_date from store_returns, date_dim 11 | where d_date_sk = sr_returned_date_sk and sr_customer_sk is not NULL); 12 | open c1; 13 | fetch next from c1 into @cust, @retDate; 14 | while(@@FETCH_STATUS=0) 15 | begin 16 | set @minDate = (select min(d_date) from store_sales, date_dim 17 | where ss_sold_date_sk=d_date_sk and ss_customer_sk=@cust 18 | and d_date>@retDate); 19 | if(DATEDIFF(MONTH, @retDate, @minDate)>=6) 20 | begin 21 | insert into @custTable values (@cust); 22 | end 23 | fetch next from c1 into @cust, @retDate; 24 | end 25 | close c1; 26 | deallocate c1; 27 | select * from @custTable; 28 | end -------------------------------------------------------------------------------- /src/T-SQL/Stored Procedures/proc4_getCustomerInfo.sql: -------------------------------------------------------------------------------- 1 | create procedure getCustomerInfo(@custKey int) 2 | as 3 | begin 4 | select c_salutation, c_first_name, c_last_name, c_birth_year, c_email_address, 5 | ca_street_number, ca_street_name, ca_suite_number, ca_city, ca_county, ca_country 6 | from customer, customer_address 7 | where c_current_addr_sk = ca_address_sk 8 | and c_customer_sk = @custKey 9 | end 10 | -------------------------------------------------------------------------------- /src/T-SQL/Stored Procedures/proc50_unsatisfiedWeb.sql: -------------------------------------------------------------------------------- 1 | --customers who after returning an order did not shop for atleast 6 months through the same channel(web). 2 | 3 | create or alter procedure unsatisfiedCustomersWeb 4 | as 5 | begin 6 | declare @cust int; 7 | declare @retDate date, @minDate date; 8 | declare @custTable table (custSk int); 9 | declare c1 cursor static for 10 | (select wr_refunded_customer_sk, d_date from web_returns, date_dim 11 | where d_date_sk = wr_returned_date_sk and wr_refunded_customer_sk is not NULL); 12 | open c1; 13 | fetch next from c1 into @cust, @retDate; 14 | while(@@FETCH_STATUS=0) 15 | begin 16 | set @minDate = (select min(d_date) from web_sales, date_dim 17 | where ws_sold_date_sk=d_date_sk and ws_bill_customer_sk=@cust 18 | and d_date>@retDate); 19 | if(DATEDIFF(MONTH, @retDate, @minDate)>=6) 20 | begin 21 | insert into @custTable values (@cust); 22 | end 23 | fetch next from c1 into @cust, @retDate; 24 | end 25 | close c1; 26 | deallocate c1; 27 | select * from @custTable; 28 | end -------------------------------------------------------------------------------- /src/T-SQL/Stored Procedures/proc51_worstsellers.sql: -------------------------------------------------------------------------------- 1 | create or alter procedure defectiveItemSellers 2 | as 3 | begin 4 | set nocount on; 5 | declare @sellerTable table (manufact int , cnt int); 6 | declare @manu int, @cnt int; 7 | 8 | declare c1 cursor for 9 | select i_manufact_id, count(*) cnt 10 | from web_returns, item, reason 11 | where wr_item_sk = i_item_sk and wr_reason_sk = r_reason_sk and 12 | wr_reason_sk is not NULL and wr_item_sk is not NULL and 13 | i_manufact_id is not NULL and 14 | (r_reason_desc = 'Parts missing' or r_reason_desc = 'Not working any more' or r_reason_desc = 'reason 38') 15 | group by i_manufact_id; 16 | 17 | open c1; 18 | fetch next from c1 into @manu, @cnt; 19 | while(@@FETCH_STATUS=0) 20 | begin 21 | if(@cnt>=20) 22 | insert into @sellerTable values (@manu, @cnt); 23 | fetch next from c1 into @manu, @cnt; 24 | end 25 | close c1; 26 | deallocate c1; 27 | select * from @sellerTable; 28 | end -------------------------------------------------------------------------------- /src/T-SQL/Stored Procedures/proc52_catalogOrderCancellation.sql: -------------------------------------------------------------------------------- 1 | --process cancellation of an order from catalog and record reason in the reason table. 2 | create or alter procedure catalogOrderCancellation (@item_sk int, @orderNo int, @reasonId int) 3 | as 4 | begin 5 | declare @shipDate date, @curDate date; 6 | declare @dateDiff int, @reasonSk int; 7 | declare @id VARCHAR(16); 8 | 9 | if not exists (select * from catalog_sales where cs_item_sk=@item_sk and cs_order_number=@orderNo) 10 | begin 11 | RAISERROR ('invalid order', 16, 10); --no such order exists. 12 | return; 13 | end 14 | 15 | set @shipDate = (select d_date from catalog_sales, date_dim 16 | where cs_ship_date_sk=d_date_sk and cs_item_sk=@item_sk and cs_order_number=@orderNo); 17 | set @dateDiff = DATEDIFF(day, @shipDate, GETDATE()); 18 | if(@dateDiff>=0) --shipdate<=today's date 19 | begin 20 | RAISERROR ('Item already shipped and cannot be cancelled. Try returning instead.',16,10); 21 | return; 22 | end 23 | else 24 | begin 25 | delete from catalog_sales where cs_item_sk=@item_sk and cs_order_number=@orderNo; 26 | if exists (select * from reason where r_reason_sk=@reasonId) 27 | return; 28 | else 29 | begin 30 | set @reasonSk = (select max(r_reason_sk)+1 from reason); 31 | EXEC dbo.CreateRandomString @id OUTPUT; 32 | --set @id = 'ABCDEFSDRGFTDVGF'; 33 | insert into reason (r_reason_sk, r_reason_id) values (@reasonSk, @id); 34 | end 35 | end 36 | end 37 | 38 | --invocation query 39 | exec dbo.catalogOrderCancellation 7273, 169579, 57 40 | go -------------------------------------------------------------------------------- /src/T-SQL/Stored Procedures/proc53_shutOldCC.sql: -------------------------------------------------------------------------------- 1 | CREATE or alter TYPE ManagerType 2 | AS TABLE 3 | (man_name varchar(40) unique, numClosed int); 4 | GO 5 | 6 | CREATE PROCEDURE ShutOldCallCenterInCounty 7 | @county varchar(30) 8 | AS 9 | BEGIN 10 | declare @closedManager ManagerType; 11 | declare @cc_sk int , @openDate int, @numEmpl int; 12 | declare @manager varchar(40)= '', @city varchar(60) = '', @year int, @numCl int; 13 | declare c1 cursor static for (select cc_call_center_sk, cc_open_date_sk, cc_employees, cc_manager, cc_city 14 | from call_center where cc_county=@county); 15 | open c1; 16 | fetch next from c1 into @cc_sk, @openDate, @numEmpl, @manager, @city 17 | while(@@fetch_status=0) 18 | begin 19 | set @year = (select d_year from date_dim where d_date_sk = @openDate); 20 | if(@year<=1998 and @numEmpl<400) 21 | begin 22 | if not exists (select * from @closedManager where man_name = @manager) 23 | insert into @closedManager values (@manager, 1); 24 | else 25 | begin 26 | set @numCl = (select numClosed from @closedManager where man_name = @manager); 27 | insert into @closedManager values (@manager, @numCl+1); 28 | end 29 | delete from call_center where cc_call_center_sk = @cc_sk; --delete this old, small CC 30 | end 31 | fetch next from c1 into @cc_sk, @openDate, @numEmpl, @city; 32 | end 33 | declare @tableName varchar(50) = '@closedManager'; 34 | select * from dbo.unemployedManagers(@closedManager); 35 | END; 36 | GO 37 | -------------------------------------------------------------------------------- /src/T-SQL/Stored Procedures/proc54_trackSaleCat.sql: -------------------------------------------------------------------------------- 1 | -- Track the sale of a particular item through catalog for 2 consecutive years. 2 | create or alter procedure trackSale_cat (@item int) 3 | as 4 | begin 5 | set nocount on; 6 | 7 | declare @compareTable table (mnth_cmpr int, sale_2001 int, sale_2002 int); 8 | declare @firstYr table (mnth int, sale_01 int); 9 | declare @secYr table (mnth int, sale_02 int); 10 | declare @month int, @sale int; 11 | 12 | insert into @firstYr 13 | select d_moy, count(*) as sl_01 from catalog_sales, date_dim 14 | where cs_sold_date_sk = d_date_sk and d_year = 2001 and cs_item_sk = @item 15 | group by d_moy; 16 | 17 | insert into @secYr 18 | select d_moy, count(*) as sl_02 from catalog_sales, date_dim 19 | where cs_sold_date_sk = d_date_sk and d_year = 2002 and cs_item_sk = @item 20 | group by d_moy; 21 | 22 | insert into @compareTable(mnth_cmpr, sale_2001) select * from @firstYr; 23 | 24 | declare c1 cursor for select * from @secYr; 25 | open c1; 26 | fetch next from c1 into @month, @sale; 27 | while(@@FETCH_STATUS=0) 28 | begin 29 | update @compareTable set sale_2002 = @sale where mnth_cmpr= @month; 30 | fetch next from c1 into @month, @sale; 31 | end 32 | close c1; 33 | deallocate c1; 34 | 35 | select * from @compareTable order by mnth_cmpr; 36 | end 37 | -------------------------------------------------------------------------------- /src/T-SQL/Stored Procedures/proc55_trackSaleStore.sql: -------------------------------------------------------------------------------- 1 | --Track the sale of a particular item through store for 2 consecutive years. 2 | create or alter procedure trackSale_store (@item int) 3 | as 4 | begin 5 | set nocount on; 6 | 7 | declare @compareTable table (mnth_cmpr int, sale_2001 int, sale_2002 int); 8 | declare @firstYr table (mnth int, sale_01 int); 9 | declare @secYr table (mnth int, sale_02 int); 10 | declare @month int, @sale int; 11 | 12 | insert into @firstYr 13 | select d_moy, count(*) as sl_01 from store_sales, date_dim 14 | where ss_sold_date_sk = d_date_sk and d_year = 2001 and ss_item_sk = @item 15 | group by d_moy; 16 | 17 | insert into @secYr 18 | select d_moy, count(*) as sl_02 from store_sales, date_dim 19 | where ss_sold_date_sk = d_date_sk and d_year = 2002 and ss_item_sk = @item 20 | group by d_moy; 21 | 22 | insert into @compareTable(mnth_cmpr, sale_2001) select * from @firstYr; 23 | 24 | declare c1 cursor for select * from @secYr; 25 | open c1; 26 | fetch next from c1 into @month, @sale; 27 | while(@@FETCH_STATUS=0) 28 | begin 29 | update @compareTable set sale_2002 = @sale where mnth_cmpr= @month; 30 | fetch next from c1 into @month, @sale; 31 | end 32 | close c1; 33 | deallocate c1; 34 | 35 | select * from @compareTable order by mnth_cmpr; 36 | 37 | end -------------------------------------------------------------------------------- /src/T-SQL/Stored Procedures/proc56_trackSaleWeb.sql: -------------------------------------------------------------------------------- 1 | -- Track the sale of a particular item through web for 2 consecutive years. 2 | create or alter procedure trackSale_web (@item int) 3 | as 4 | begin 5 | set nocount on; 6 | 7 | declare @compareTable table (mnth_cmpr int, sale_2001 int, sale_2002 int); 8 | declare @firstYr table (mnth int, sale_01 int); 9 | declare @secYr table (mnth int, sale_02 int); 10 | declare @month int, @sale int; 11 | 12 | insert into @firstYr 13 | select d_moy, count(*) as sl_01 from web_sales, date_dim 14 | where ws_sold_date_sk = d_date_sk and d_year = 2001 and ws_item_sk = @item 15 | group by d_moy; 16 | 17 | insert into @secYr 18 | select d_moy, count(*) as sl_02 from web_sales, date_dim 19 | where ws_sold_date_sk = d_date_sk and d_year = 2002 and ws_item_sk = @item 20 | group by d_moy; 21 | 22 | insert into @compareTable(mnth_cmpr, sale_2001) select * from @firstYr; 23 | 24 | declare c1 cursor for select * from @secYr; 25 | open c1; 26 | fetch next from c1 into @month, @sale; 27 | while(@@FETCH_STATUS=0) 28 | begin 29 | update @compareTable set sale_2002 = @sale where mnth_cmpr= @month; 30 | fetch next from c1 into @month, @sale; 31 | end 32 | close c1; 33 | deallocate c1; 34 | 35 | select * from @compareTable order by mnth_cmpr; 36 | 37 | end -------------------------------------------------------------------------------- /src/T-SQL/Stored Procedures/proc57_webOrderCancellation.sql: -------------------------------------------------------------------------------- 1 | --process cancellation of an order fromm web and record reason in the reason table. 2 | 3 | create or alter procedure webOrderCancellation (@item_sk int, @orderNo int, @reasonId int) 4 | as 5 | begin 6 | declare @soldDate date, @curDate date; 7 | declare @dateDiff int, @reasonSk int; 8 | declare @id VARCHAR(16); 9 | 10 | if not exists (select * from web_sales where ws_item_sk=@item_sk and ws_order_number=@orderNo) 11 | begin 12 | RAISERROR ('invalid order', 16, 10); 13 | return; 14 | end 15 | 16 | set @soldDate = (select d_date from web_sales, date_dim 17 | where ws_sold_date_sk=d_date_sk and ws_item_sk=@item_sk and ws_order_number=@orderNo); 18 | set @dateDiff = DATEDIFF(day, @soldDate, GETDATE()); 19 | if(@dateDiff>30) 20 | begin 21 | RAISERROR ('Item not eligible for return',16,10); 22 | return; 23 | end 24 | else 25 | begin 26 | delete from web_sales where ws_item_sk=@item_sk and ws_order_number=@orderNo; 27 | if exists (select * from reason where r_reason_sk=@reasonId) 28 | return; 29 | else 30 | begin 31 | set @reasonSk = (select max(r_reason_sk)+1 from reason); 32 | EXEC dbo.CreateRandomString @id OUTPUT; 33 | insert into reason (r_reason_sk, r_reason_id) values (@reasonSk, @id); 34 | end 35 | end 36 | end 37 | 38 | -------------------------------------------------------------------------------- /src/T-SQL/Stored Procedures/proc5_getImmigrantCust.sql: -------------------------------------------------------------------------------- 1 | create or alter procedure getImmigrantCustomers 2 | as 3 | begin 4 | set nocount on; 5 | 6 | select c_customer_sk, c_birth_country, ca_state as currentState, cd_gender, cd_marital_status, 7 | cd_education_status, ib_lower_bound, ib_upper_bound, 8 | cd_credit_rating, cd_dep_count 9 | from customer, customer_address, household_demographics, income_band, customer_demographics 10 | where c_current_addr_sk = ca_address_sk 11 | and c_birth_country != ca_country 12 | and c_current_hdemo_sk=hd_demo_sk 13 | and hd_income_band_sk = ib_income_band_sk 14 | and cd_demo_sk = c_current_cdemo_sk 15 | and c_customer_sk is not NULL; 16 | end 17 | -------------------------------------------------------------------------------- /src/T-SQL/Stored Procedures/proc62_totalCustLoss.sql: -------------------------------------------------------------------------------- 1 | create or alter procedure custTotalLoss(@returnReason char(100)) 2 | as 3 | begin 4 | declare @orderNo int, @item int; 5 | declare @reasonSk int; 6 | declare @soldAmt decimal(7, 2), @retCredit decimal(7, 2); 7 | declare @totalCustLoss decimal(15, 0); 8 | 9 | set @totalCustLoss=0; 10 | set @reasonSk = (select r_reason_sk from reason where r_reason_desc=@returnReason); 11 | declare c1 cursor for (select wr_order_number, wr_item_sk, wr_refunded_cash from web_returns where wr_reason_sk=1); 12 | open c1; 13 | fetch next from c1 into @orderNo, @item, @retCredit; 14 | while(@@FETCH_STATUS=0) 15 | begin 16 | set @soldAmt = (select ws_net_paid_inc_ship_tax from web_sales where ws_order_number = @orderNo and ws_item_sk=@item); 17 | set @totalCustLoss += @soldAmt - @retCredit ; 18 | fetch next from c1 into @orderNo, @item, @retCredit; 19 | end 20 | close c1; 21 | 22 | declare c2 cursor for (select cr_order_number, cr_item_sk, cr_refunded_cash from catalog_returns where cr_reason_sk=1); 23 | open c2; 24 | fetch next from c2 into @orderNo, @item, @retCredit; 25 | while(@@FETCH_STATUS=0) 26 | begin 27 | set @soldAmt = (select cs_net_paid_inc_ship_tax from catalog_sales where cs_order_number = @orderNo and cs_item_sk=@item); 28 | set @totalCustLoss += @soldAmt - @retCredit; 29 | fetch next from c2 into @orderNo, @item, @retCredit; 30 | end 31 | select @totalCustLoss as totalLossToCustomer; 32 | 33 | close c2; 34 | deallocate c1; 35 | deallocate c2; 36 | end -------------------------------------------------------------------------------- /src/T-SQL/Stored Procedures/proc63_accessItemQuality.sql: -------------------------------------------------------------------------------- 1 | create or alter procedure AccessItemQuality 2 | as 3 | begin 4 | declare @mostReturnItem table(itemNo int, manufactId int); 5 | insert into @mostReturnItem select * from dbo.MaxRetunItems(); 6 | delete from item where i_item_sk in (select itemNo from @mostReturnItem); --these items deleted 7 | update item set i_item_desc = 'HIGH RISH ITEM' where i_manufact_id in (select manufactId from @mostReturnItem); 8 | end -------------------------------------------------------------------------------- /src/T-SQL/Stored Procedures/proc6_getNativeCust.sql: -------------------------------------------------------------------------------- 1 | create or alter procedure getNativeCustomers 2 | as 3 | begin 4 | set nocount on; 5 | 6 | select c_customer_sk, ca_state, cd_gender, cd_marital_status, 7 | cd_education_status, ib_lower_bound, ib_upper_bound, 8 | cd_credit_rating, cd_dep_count 9 | from customer, customer_address, household_demographics, income_band, customer_demographics 10 | where c_current_addr_sk = ca_address_sk 11 | and c_birth_country=ca_country 12 | and c_current_hdemo_sk=hd_demo_sk 13 | and hd_income_band_sk = ib_income_band_sk 14 | and cd_demo_sk = c_current_cdemo_sk 15 | and c_customer_sk is not NULL; 16 | end 17 | -------------------------------------------------------------------------------- /src/T-SQL/Stored Procedures/proc7_lowIncomeCustWithHighPurchase.sql: -------------------------------------------------------------------------------- 1 | --cusotmers belonging to a low income band and who made purchases of more than a given amount. 2 | 3 | CREATE PROCEDURE lowIncomeCustomerWithHighPurchaseAmount(@amount decimal(7, 2)) 4 | AS 5 | BEGIN 6 | set nocount on; 7 | 8 | select distinct ss_customer_sk, ib_income_band_sk 9 | from store_sales_history, household_demographics, income_band 10 | where ss_hdemo_sk = hd_demo_sk 11 | and hd_income_band_sk = ib_income_band_sk 12 | and ss_net_paid_inc_tax>@amount 13 | and ib_income_band_sk<=4 14 | END -------------------------------------------------------------------------------- /src/T-SQL/Stored Procedures/proc8_multiStateShoppers_2.sql: -------------------------------------------------------------------------------- 1 | --Customers who have shopped in stores from more than 1 state in a given year and month 2 | create or alter procedure multiStateShoppers (@year int, @moy int) 3 | as 4 | begin 5 | declare @custTable Table (cust int, cnt int); 6 | 7 | insert into @custTable 8 | select ss_customer_sk, count(*) from 9 | (select distinct ss_customer_sk, s_state 10 | from store_sales_history, date_dim, store 11 | where ss_sold_date_sk = d_date_sk and ss_store_sk = s_store_sk 12 | and d_year = @year and d_moy =@moy and ss_customer_sk is not NULL and ss_store_sk is not NULL 13 | )t 14 | group by ss_customer_sk 15 | order by ss_customer_sk; 16 | 17 | select * from @custTable where cnt>1 order by cust; 18 | end 19 | -------------------------------------------------------------------------------- /src/T-SQL/Stored Procedures/proc9_popularWP.sql: -------------------------------------------------------------------------------- 1 | --how may people shopped from a web_page 2 | create procedure popularWebPages 3 | as 4 | begin 5 | set nocount on; 6 | 7 | select top 100 ws_web_page_sk,count(*) as cnt from web_sales_history, web_page 8 | where ws_web_page_sk = wp_web_page_sk 9 | group by ws_web_page_sk 10 | order by cnt desc 11 | end 12 | go -------------------------------------------------------------------------------- /src/T-SQL/Table Valued UDFs/TVF3_maxProfitsales.sql: -------------------------------------------------------------------------------- 1 | --Compute store sales net profit ranking by state and city for a given year 2 | --and determine the five most profitable states. 3 | 4 | Create or Alter Function dbo.maxProfitStates(@givenYear int) 5 | RETURNS @profitRanking TABLE(state char(2), city varchar(60), profit decimal(15, 2)) 6 | as 7 | begin 8 | insert into @profitRanking 9 | select top 5 s_state, s_city, sum(ss_net_profit) as totalProfit 10 | from store_sales_history, store, date_dim 11 | where ss_store_sk = s_store_sk 12 | and ss_sold_date_sk = d_date_sk 13 | and d_year = @givenYear 14 | group by s_state, s_city 15 | order by totalProfit desc; 16 | 17 | return; 18 | end 19 | go 20 | 21 | --invocation query 22 | SELECT date_dim.d_year, 23 | Results.state, 24 | Results.city, 25 | Results.profit 26 | FROM date_dim 27 | OUTER APPLY dbo.maxProfitStates(d_year) AS Results 28 | where results.profit IS NOT NULL 29 | group by d_year, Results.state, Results.city, 30 | Results.profit 31 | order by d_year desc 32 | 33 | 34 | -------------------------------------------------------------------------------- /src/T-SQL/Table Valued UDFs/TVF4a_bestpromoWeb.sql: -------------------------------------------------------------------------------- 1 | --highest profit earning promos on the web 2 | 3 | create or alter function bestPromosWeb() 4 | returns @bestPromoWeb TABLE(promo_sk int, profit_web decimal(15,2)) 5 | as 6 | begin 7 | 8 | insert into @bestPromoWeb 9 | select top 5 ws_promo_sk, sum(ws_net_profit) as posProfit from web_sales_history 10 | where ws_net_profit>0 11 | and ws_promo_sk is not NULL 12 | group by ws_promo_sk 13 | order by posProfit desc 14 | 15 | return; 16 | end 17 | go -------------------------------------------------------------------------------- /src/T-SQL/Table Valued UDFs/TVF4b_bestPromoCatalog.sql: -------------------------------------------------------------------------------- 1 | --highest profit earning promos on the catalog 2 | 3 | create or alter function bestPromosCatalog() 4 | returns @bestPromoCat TABLE(promo_sk int, profit_cat decimal(15,2)) 5 | as 6 | begin 7 | 8 | insert into @bestPromoCat 9 | select top 5 cs_promo_sk, sum(cs_net_profit) as posProfit from catalog_sales_history 10 | where cs_net_profit>0 11 | and cs_promo_sk is not NULL 12 | group by cs_promo_sk 13 | order by posProfit desc 14 | 15 | return; 16 | 17 | end 18 | go -------------------------------------------------------------------------------- /src/T-SQL/Table Valued UDFs/TVF4c_bestPromoStore.sql: -------------------------------------------------------------------------------- 1 | --highest profit earning promos through stores 2 | 3 | create or alter function bestPromoStore() 4 | returns @bestPromoStore TABLE(promo_sk int, profit_store decimal(15,2)) 5 | as 6 | begin 7 | 8 | insert into @bestPromoStore 9 | select top 5 ss_promo_sk, sum(ss_net_profit) as posProfit from store_sales_history 10 | where ss_net_profit>0 11 | and ss_promo_sk is not NULL 12 | group by ss_promo_sk 13 | order by posProfit desc 14 | 15 | return; 16 | 17 | end 18 | go -------------------------------------------------------------------------------- /src/T-SQL/Table Valued UDFs/TVF5-unemployedManager.sql: -------------------------------------------------------------------------------- 1 | CREATE TYPE ManagerType 2 | AS TABLE 3 | (man_name varchar(40) unique, numClosed int); 4 | GO 5 | 6 | CREATE or alter function unemployedManagers (@closedManagers ManagerType readonly) 7 | RETURNS @unemployedMan table (manName varchar(40)) 8 | AS 9 | BEGIN 10 | declare @manager varchar(40); 11 | declare c1 cursor for (select man_name from @closedManagers); 12 | open c1; 13 | fetch next from c1 into @manager; 14 | while(@@fetch_status=0) 15 | begin 16 | if not exists (select * from call_center where cc_manager = @manager) 17 | begin 18 | insert into @unemployedMan values (@manager); 19 | end 20 | fetch next from c1 into @manager; 21 | end 22 | return; 23 | END 24 | go 25 | 26 | --given a list of call-center manager names, find which of these are currently unemployed. This is called from stored procedure proc_53_shutOldCC -------------------------------------------------------------------------------- /src/T-SQL/Table Valued UDFs/TVF6-bestStoreForCategories.sql: -------------------------------------------------------------------------------- 1 | --top stores for each category based on the number of items sold 2 | create or alter function bestStoreForCatgory() 3 | returns @relation table (category char(50), store int) 4 | as 5 | begin 6 | declare @cat char(50); 7 | declare @maxStore int; 8 | declare c1 cursor for (select distinct i_category from item where i_category is not null) 9 | open c1; 10 | fetch next from c1 into @cat; 11 | while(@@FETCH_STATUS=0) 12 | begin 13 | set @maxStore = (select ss_store_sk from ( 14 | select top 1 ss_store_sk, count(*) as cnt 15 | from store_sales, item 16 | where ss_item_sk = i_item_sk and i_category = @cat and ss_store_sk is not NULL 17 | group by ss_store_sk 18 | order by cnt desc)t); 19 | insert into @relation values (@cat, @maxStore); 20 | fetch next from c1 into @cat; 21 | end 22 | return; 23 | end 24 | go -------------------------------------------------------------------------------- /src/T-SQL/Table Valued UDFs/TVF7_profitMonitoring.sql: -------------------------------------------------------------------------------- 1 | --analyse the profit of a store for a given duration. 2 | create or alter function profitMonitoring(@startDate date, @endDate date, @givenStore int) 3 | returns @profitTable table(dt date, profit decimal(15, 2)) 4 | as 5 | begin 6 | if(@startDate>@endDate) 7 | return; 8 | declare @dateSk int; 9 | declare @dayProfit decimal (15, 2); 10 | while(@startDate<=@endDate) 11 | begin 12 | set @dateSk = (select d_date_sk from date_dim where d_date = @startDate) 13 | set @dayProfit = (select sum(ss_net_profit) 14 | from store_sales_history 15 | where ss_sold_date_sk=@dateSk and ss_store_sk = @givenStore); 16 | 17 | insert into @profitTable values (@startDate, @dayProfit); 18 | set @startDate = DATEADD(dy, 1, @startDate); 19 | end 20 | return; 21 | end 22 | go -------------------------------------------------------------------------------- /src/T-SQL/Table Valued UDFs/TVF8_MaxReturnItems.sql: -------------------------------------------------------------------------------- 1 | --Out of the 1000 most returned items across all the sales channel, find the ones that are outdated. 2 | 3 | create or alter function MaxReturnItems() 4 | returns @maxretItems table (itemNo int, manufactId int) 5 | as 6 | begin 7 | declare @itemNo int, @manufact int; 8 | declare @recDate date; 9 | declare @itemTbl table (itemNo int, cnt int); 10 | 11 | insert into @itemTbl 12 | select top 1000 cr_item_sk, count(cnt) totalCnt 13 | from 14 | (select cr_item_sk, count(*) cnt from catalog_returns group by cr_item_sk 15 | union all 16 | select wr_item_sk, count(*) cnt from web_returns group by wr_item_sk 17 | union all 18 | select sr_item_sk, count(*) cnt from store_returns group by sr_item_sk)t 19 | group by cr_item_sk 20 | order by totalCnt desc 21 | 22 | declare c1 cursor for select itemNo from @itemTbl; 23 | open c1; 24 | fetch next from c1 into @itemNo; 25 | while(@@FETCH_STATUS=0) 26 | begin 27 | set @recDate = (select i_rec_start_date from item where i_item_sk = @itemNo); 28 | set @manufact = (select i_manufact_id from item where i_item_sk = @itemNo); 29 | if(DATEDIFF(day, @recDate, '2000-01-01')>0) 30 | insert into @maxretItems values (@itemNo, @manufact); 31 | fetch next from c1 into @itemNo; 32 | end 33 | close c1; 34 | deallocate c1; 35 | return; 36 | end 37 | go -------------------------------------------------------------------------------- /src/T-SQL/Triggers/Trigger1_AfterInsert_dateTable.sql: -------------------------------------------------------------------------------- 1 | CREATE or ALTER TRIGGER dateTableChanges ON date_dim 2 | after INSERT 3 | AS 4 | declare @year int, @month int, @day int; 5 | declare @date date; 6 | set @year = (select d_year from inserted); 7 | set @month = (select d_moy from inserted); 8 | set @day = (select d_dom from inserted); 9 | set @date = (select d_date from inserted); 10 | 11 | if(@year=NULL or @year<2100 or (@year=2100 and @month=01 and @day=01)) 12 | begin 13 | RAISERROR('illegal insert in date table', 10, 1); 14 | rollback transaction; 15 | return; 16 | end 17 | 18 | if(@date is NULL and (@year is NULL or @month is NULL or @day is NULL)) 19 | begin 20 | RAISERROR('cannot insert incomplete date information', 10, 1); 21 | rollback transaction; 22 | return; 23 | end 24 | 25 | if(@date is not NULL) 26 | begin 27 | declare @dDay int = DAY(@date); 28 | declare @dMonth int = MONTH(@date); 29 | declare @dYear int = YEAR(@date); 30 | if((@year is not NULL and @year!=@dYear) or (@month is not NULL and @month!=@dMonth) or (@day is not NULL and @day!=@dDay)) 31 | begin 32 | RAISERROR('Inconsistent data values', 10, 1); 33 | rollback transaction; 34 | return; 35 | end 36 | end 37 | 38 | GO 39 | 40 | --invocation query 41 | insert into date_dim (d_date_sk, d_date_id, d_date, d_year, d_moy, d_dom) values (3488070, 'ACHOFIRSYCHGRUFG', '3022-01-19', 3022, 01, 19); -------------------------------------------------------------------------------- /src/T-SQL/Triggers/Trigger3_afterUpdate_promo.sql: -------------------------------------------------------------------------------- 1 | CREATE or ALTER TRIGGER promo_update ON promotion 2 | AFTER UPDATE 3 | AS 4 | insert into logTable 5 | select 'promo sk number ' + cast(i.p_promo_sk as varchar(max))+ ' re-activated', getDate() 6 | from deleted d, inserted i 7 | where d.p_promo_sk = i.p_promo_sk 8 | and d.p_discount_active='N' and i.p_discount_active='Y'; 9 | 10 | GO 11 | 12 | --invocation query 13 | update promotion set p_discount_active='N' where p_promo_sk>=200 and p_promo_sk<400; -------------------------------------------------------------------------------- /src/T-SQL/Triggers/Trigger5_afterDelete_catPage.sql: -------------------------------------------------------------------------------- 1 | CREATE or ALTER TRIGGER deleteCatPage ON catalog_page 2 | AFTER DELETE 3 | AS 4 | declare @catalog_page int; 5 | declare @type varchar(100); 6 | declare c1 cursor static for (select cp_catalog_page_sk, cp_type from DELETED); 7 | open c1; 8 | fetch next from c1 into @catalog_page, @type; 9 | while(@@fetch_status=0) 10 | begin 11 | if(@type='monthly ') 12 | begin 13 | raiserror('cannot delete page from monthly catalog as per policy', 10, 1); 14 | rollback transaction; 15 | end 16 | else 17 | begin 18 | DELETE from catalog_sales where cs_catalog_page_sk = @catalog_page; 19 | DELETE from catalog_returns where cr_catalog_page_sk = @catalog_page; 20 | end 21 | fetch next from c1 into @catalog_page, @type; 22 | end 23 | close c1; 24 | deallocate c1; 25 | GO 26 | 27 | --invocation query 28 | delete from catalog_page where cp_description like '%weapon%'; -------------------------------------------------------------------------------- /src/T-SQL/Triggers/Trigger6_afterDelete_customer.sql: -------------------------------------------------------------------------------- 1 | CREATE or ALTER TRIGGER deleteCustomer ON customer 2 | AFTER DELETE 3 | AS 4 | declare @cust_sk int; 5 | declare c2 cursor static for (select c_customer_sk from DELETED); 6 | open c2; 7 | fetch next from c2 into @cust_sk; 8 | while(@@fetch_status=0) 9 | begin 10 | UPDATE web_page set wp_customer_sk=NULL where wp_customer_sk = @cust_sk; 11 | DELETE from web_returns where wr_refunded_customer_sk = @cust_sk or wr_returning_customer_sk=@cust_sk; 12 | DELETE from catalog_returns where cr_refunded_customer_sk = @cust_sk or cr_returning_customer_sk=@cust_sk; 13 | DELETE from store_returns where sr_customer_sk = @cust_sk; 14 | 15 | DELETE from web_sales where ws_bill_customer_sk = @cust_sk or ws_ship_customer_sk=@cust_sk; 16 | DELETE from catalog_sales where cs_bill_customer_sk = @cust_sk or cs_ship_customer_sk=@cust_sk; 17 | DELETE from store_sales where ss_customer_sk = @cust_sk; 18 | fetch next from c2 into @cust_sk; 19 | end 20 | close c2; 21 | deallocate c2; 22 | GO 23 | 24 | --DML to invoke 25 | delete from customer where c_customer_sk=1 --------------------------------------------------------------------------------