Biskilog POS desktop appilcation
You can not select more than 25 topics Topics must start with a letter or number, can include dashes ('-') and can be up to 35 characters long.

1372 lines
107 KiB

USE [master]
GO
/****** Object: Database [BISK_POS] Script Date: 03/07/2020 11:51:15 ******/
CREATE DATABASE [BISK_POS]
GO
ALTER DATABASE [BISK_POS] SET COMPATIBILITY_LEVEL = 150
GO
IF (1 = FULLTEXTSERVICEPROPERTY('IsFullTextInstalled'))
begin
EXEC [BISK_POS].[dbo].[sp_fulltext_database] @action = 'enable'
end
GO
ALTER DATABASE [BISK_POS] SET ANSI_NULL_DEFAULT OFF
GO
ALTER DATABASE [BISK_POS] SET ANSI_NULLS OFF
GO
ALTER DATABASE [BISK_POS] SET ANSI_PADDING OFF
GO
ALTER DATABASE [BISK_POS] SET ANSI_WARNINGS OFF
GO
ALTER DATABASE [BISK_POS] SET ARITHABORT OFF
GO
ALTER DATABASE [BISK_POS] SET AUTO_CLOSE OFF
GO
ALTER DATABASE [BISK_POS] SET AUTO_SHRINK OFF
GO
ALTER DATABASE [BISK_POS] SET AUTO_UPDATE_STATISTICS ON
GO
ALTER DATABASE [BISK_POS] SET CURSOR_CLOSE_ON_COMMIT OFF
GO
ALTER DATABASE [BISK_POS] SET CURSOR_DEFAULT GLOBAL
GO
ALTER DATABASE [BISK_POS] SET CONCAT_NULL_YIELDS_NULL OFF
GO
ALTER DATABASE [BISK_POS] SET NUMERIC_ROUNDABORT OFF
GO
ALTER DATABASE [BISK_POS] SET QUOTED_IDENTIFIER OFF
GO
ALTER DATABASE [BISK_POS] SET RECURSIVE_TRIGGERS OFF
GO
ALTER DATABASE [BISK_POS] SET DISABLE_BROKER
GO
ALTER DATABASE [BISK_POS] SET AUTO_UPDATE_STATISTICS_ASYNC OFF
GO
ALTER DATABASE [BISK_POS] SET DATE_CORRELATION_OPTIMIZATION OFF
GO
ALTER DATABASE [BISK_POS] SET TRUSTWORTHY OFF
GO
ALTER DATABASE [BISK_POS] SET ALLOW_SNAPSHOT_ISOLATION OFF
GO
ALTER DATABASE [BISK_POS] SET PARAMETERIZATION SIMPLE
GO
ALTER DATABASE [BISK_POS] SET READ_COMMITTED_SNAPSHOT OFF
GO
ALTER DATABASE [BISK_POS] SET HONOR_BROKER_PRIORITY OFF
GO
ALTER DATABASE [BISK_POS] SET RECOVERY SIMPLE
GO
ALTER DATABASE [BISK_POS] SET MULTI_USER
GO
ALTER DATABASE [BISK_POS] SET PAGE_VERIFY CHECKSUM
GO
ALTER DATABASE [BISK_POS] SET DB_CHAINING OFF
GO
ALTER DATABASE [BISK_POS] SET FILESTREAM( NON_TRANSACTED_ACCESS = OFF )
GO
ALTER DATABASE [BISK_POS] SET TARGET_RECOVERY_TIME = 60 SECONDS
GO
ALTER DATABASE [BISK_POS] SET DELAYED_DURABILITY = DISABLED
GO
ALTER DATABASE [BISK_POS] SET QUERY_STORE = OFF
GO
USE [BISK_POS]
GO
CREATE LOGIN [bisk] WITH PASSWORD='bisk', DEFAULT_DATABASE=[BISK_POS], DEFAULT_LANGUAGE=[us_english], CHECK_EXPIRATION=OFF, CHECK_POLICY=OFF
GO
/****** Object: User [bisk] Script Date: 03/07/2020 11:51:16 ******/
CREATE LOGIN [biskpos] WITH PASSWORD='bisk2020', DEFAULT_DATABASE=[BISK_POS], DEFAULT_LANGUAGE=[us_english], CHECK_EXPIRATION=OFF, CHECK_POLICY=OFF
GO
ALTER ROLE [db_datareader] ADD MEMBER [biskpos]
GO
ALTER ROLE [db_datawriter] ADD MEMBER [biskpos]
GO
ALTER ROLE [db_owner] ADD MEMBER [bisk]
GO
ALTER ROLE [db_datareader] ADD MEMBER [bisk]
GO
ALTER ROLE [db_datawriter] ADD MEMBER [bisk]
GO
/****** Object: Table [dbo].[CreditPurchases] Script Date: 04/10/2020 13:45:32 ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE TABLE [dbo].[CreditPurchases](
[receiptID] [nvarchar](120) NOT NULL,
[date] [datetime2](7) NULL,
[paid] [decimal](19, 2) NULL,
[totalBill] [decimal](19, 2) NULL,
[customerID] [nvarchar](120) NULL,
[status] [varchar](10) NULL,
[branchID] [varchar](10) NULL,
CONSTRAINT [PK_CreditPurchases] PRIMARY KEY CLUSTERED
(
[receiptID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, OPTIMIZE_FOR_SEQUENTIAL_KEY = OFF) ON [PRIMARY]
) ON [PRIMARY]
GO
/****** Object: Table [dbo].[CustomerAccounts] Script Date: 04/10/2020 13:45:32 ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE TABLE [dbo].[CustomerAccounts](
[customerID] [nvarchar](120) NULL,
[transactionID] [nvarchar](120) NULL,
[date] [datetime2](7) NULL,
[debit] [decimal](19, 2) NULL,
[credit] [decimal](19, 2) NULL,
[balance] [decimal](19, 2) NULL,
[comments] [varchar](max) NULL,
[branchID] [varchar](10) NULL,
[countID] [nvarchar](120) NOT NULL,
CONSTRAINT [PK_CustomerAccounts] PRIMARY KEY CLUSTERED
(
[countID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, OPTIMIZE_FOR_SEQUENTIAL_KEY = OFF) ON [PRIMARY]
) ON [PRIMARY] TEXTIMAGE_ON [PRIMARY]
GO
/****** Object: Table [dbo].[ProductAltUnit] Script Date: 04/10/2020 13:45:32 ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE TABLE [dbo].[ProductAltUnit](
[pcode] [varchar](120) NULL,
[unitCode] [varchar](120) NULL,
[unitBarcode] [varchar](20) NULL,
[price/unit] [decimal](19, 2) NULL,
[quantity/unit] [int] NULL,
[distinctiveCode] [varchar](120) NOT NULL,
[branchID] [varchar](120) NULL,
CONSTRAINT [PK_ProductUnitPricing] PRIMARY KEY CLUSTERED
(
[distinctiveCode] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, OPTIMIZE_FOR_SEQUENTIAL_KEY = OFF) ON [PRIMARY]
) ON [PRIMARY]
GO
/****** Object: Table [dbo].[systemUserRoles] Script Date: 04/10/2020 13:45:32 ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE TABLE [dbo].[systemUserRoles](
[roles] [varchar](max) NULL,
[owner] [bit] NULL,
[manager] [bit] NULL,
[assist] [bit] NULL,
[cashier] [bit] NULL,
[id] [int] NOT NULL,
CONSTRAINT [PK_systemUserRoles] PRIMARY KEY CLUSTERED
(
[id] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, OPTIMIZE_FOR_SEQUENTIAL_KEY = OFF) ON [PRIMARY]
) ON [PRIMARY] TEXTIMAGE_ON [PRIMARY]
GO
/****** Object: Table [dbo].[tblBranches] Script Date: 04/10/2020 13:45:32 ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE TABLE [dbo].[tblBranches](
[branchName] [varchar](50) NULL,
[branchID] [nvarchar](12) NOT NULL,
[address] [varchar](50) NULL,
[city] [varchar](50) NULL,
[state_or_province] [varchar](50) NULL,
[branch_telephone] [varchar](50) NULL,
CONSTRAINT [PK_tblBranches] PRIMARY KEY CLUSTERED
(
[branchID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, OPTIMIZE_FOR_SEQUENTIAL_KEY = OFF) ON [PRIMARY]
) ON [PRIMARY]
GO
/****** Object: Table [dbo].[tblBrand] Script Date: 04/10/2020 13:45:32 ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE TABLE [dbo].[tblBrand](
[id] [nvarchar](50) NOT NULL,
[brand] [varchar](50) NULL,
[branchID] [nvarchar](12) NULL,
CONSTRAINT [PK_tblBrand] PRIMARY KEY CLUSTERED
(
[id] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, OPTIMIZE_FOR_SEQUENTIAL_KEY = OFF) ON [PRIMARY]
) ON [PRIMARY]
GO
/****** Object: Table [dbo].[tblCancelledTransactions] Script Date: 04/10/2020 13:45:32 ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE TABLE [dbo].[tblCancelledTransactions](
[transno] [varchar](max) NULL,
[dateCancelled] [datetime] NULL,
[cancelledBy] [varchar](50) NULL,
[branchID] [nvarchar](50) NULL,
[countID] [nvarchar](50) NOT NULL,
CONSTRAINT [PK_tblCancelledTransactions] PRIMARY KEY CLUSTERED
(
[countID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, OPTIMIZE_FOR_SEQUENTIAL_KEY = OFF) ON [PRIMARY]
) ON [PRIMARY] TEXTIMAGE_ON [PRIMARY]
GO
USE [BISK_POS]
GO
USE [BISK_POS]
GO
/****** Object: Table [dbo].[tblCart] Script Date: 01/05/2022 12:13:31 am ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE TABLE [dbo].[tblCart](
[transno] [nvarchar](max) NULL,
[id] [nvarchar](50) NULL,
[quantity] [int] NULL,
[date] [datetime2](7) NULL,
[price] [decimal](19, 2) NULL,
[cashier] [nvarchar](50) NULL,
[status] [varchar](50) NULL,
[total] [decimal](19, 2) NULL,
[branchID] [nvarchar](12) NULL,
[unit] [varchar](120) NULL,
[costprice] [decimal](19, 2) NULL,
[tendered] [decimal](19, 2) NULL,
[balance] [decimal](19, 2) NULL,
[valueAddTax] [decimal](19, 2) NULL,
[countID] [varchar](200) NOT NULL,
CONSTRAINT [PK_tblCart] PRIMARY KEY CLUSTERED
(
[countID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, OPTIMIZE_FOR_SEQUENTIAL_KEY = OFF) ON [PRIMARY]
) ON [PRIMARY] TEXTIMAGE_ON [PRIMARY]
GO
ALTER TABLE [dbo].[tblCart] ADD CONSTRAINT [DF_tblCart_tendered] DEFAULT ((0)) FOR [tendered]
GO
ALTER TABLE [dbo].[tblCart] ADD CONSTRAINT [DF_tblCart_balance] DEFAULT ((0)) FOR [balance]
GO
/****** Object: Table [dbo].[tblCategory] Script Date: 04/10/2020 13:45:32 ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE TABLE [dbo].[tblCategory](
[id] [nvarchar](50) NOT NULL,
[category] [varchar](50) NULL,
[branchID] [nvarchar](12) NULL,
CONSTRAINT [PK_tblCategory] PRIMARY KEY CLUSTERED
(
[id] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, OPTIMIZE_FOR_SEQUENTIAL_KEY = OFF) ON [PRIMARY]
) ON [PRIMARY]
GO
/****** Object: Table [dbo].[tblCompanyDetails] Script Date: 04/10/2020 13:45:32 ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE TABLE [dbo].[tblCompanyDetails](
[company_name] [varchar](50) NULL,
[address] [varchar](50) NULL,
[website] [varchar](50) NULL,
[email] [varchar](50) NULL,
[tin] [nvarchar](60) NOT NULL,
[main_telephone] [nvarchar](50) NULL,
[vatno] [nvarchar](60) NULL,
CONSTRAINT [PK_tblCompanyDetails] PRIMARY KEY CLUSTERED
(
[tin] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, OPTIMIZE_FOR_SEQUENTIAL_KEY = OFF) ON [PRIMARY]
) ON [PRIMARY]
GO
/****** Object: Table [dbo].[tblCustomerPurchases] Script Date: 04/10/2020 13:45:32 ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE TABLE [dbo].[tblCustomerPurchases](
[customerID] [nvarchar](50) NULL,
[transactionID] [nvarchar](50) NULL,
[branchID] [varchar](50) NULL,
[countID] [nvarchar](50) NOT NULL,
CONSTRAINT [PK_tblCustomerPurchases] PRIMARY KEY CLUSTERED
(
[countID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, OPTIMIZE_FOR_SEQUENTIAL_KEY = OFF) ON [PRIMARY]
) ON [PRIMARY]
GO
/****** Object: Table [dbo].[tblCustomers] Script Date: 04/10/2020 13:45:32 ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE TABLE [dbo].[tblCustomers](
[customerID] [nvarchar](30) NOT NULL,
[Firstname] [varchar](50) NULL,
[Surname] [varchar](50) NULL,
[address] [varchar](50) NULL,
[telephone] [varchar](50) NULL,
[dateAdded] [date] NULL,
[branchID] [nvarchar](50) NULL,
[status] [varchar](20) NULL,
[tin] [nvarchar](50) NULL,
[dateExit] [date] NULL,
[email] [nvarchar](50) NULL,
[financialStatus] [varchar](20) NULL,
[name_key1] [varchar](120) NULL,
[name_key2] [varchar](120) NULL,
CONSTRAINT [PK_tblCustomers] PRIMARY KEY CLUSTERED
(
[customerID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, OPTIMIZE_FOR_SEQUENTIAL_KEY = OFF) ON [PRIMARY]
) ON [PRIMARY]
GO
/****** Object: Table [dbo].[tblDeliveryDetails] Script Date: 04/10/2020 13:45:32 ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE TABLE [dbo].[tblDeliveryDetails](
[deliveryID] [nvarchar](60) NULL,
[pcode] [nvarchar](60) NULL,
[quantity] [int] NULL,
[unit] [varchar](120) NULL,
[cost] [decimal](19, 2) NULL,
[countID] [nvarchar](100) NOT NULL,
CONSTRAINT [PK_tblDeliveryDetails] PRIMARY KEY CLUSTERED
(
[countID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, OPTIMIZE_FOR_SEQUENTIAL_KEY = OFF) ON [PRIMARY]
) ON [PRIMARY]
GO
/****** Object: Table [dbo].[tblDeliveryHead] Script Date: 04/10/2020 13:45:32 ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE TABLE [dbo].[tblDeliveryHead](
[deliveryID] [nvarchar](60) NOT NULL,
[generatedBy] [varchar](50) NULL,
[dateInitiated] [datetime2](7) NULL,
[dateCompleted] [datetime2](7) NULL,
[destination] [nvarchar](60) NULL,
[customerID] [nvarchar](60) NULL,
[totalCost] [decimal](19, 2) NULL,
[status] [varchar](20) NULL,
[branchID] [nvarchar](20) NULL,
CONSTRAINT [PK_tblDeliveryHead] PRIMARY KEY CLUSTERED
(
[deliveryID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, OPTIMIZE_FOR_SEQUENTIAL_KEY = OFF) ON [PRIMARY]
) ON [PRIMARY]
GO
/****** Object: Table [dbo].[tblDeliveryRecipients] Script Date: 04/10/2020 13:45:32 ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE TABLE [dbo].[tblDeliveryRecipients](
[deliveryID] [nvarchar](60) NOT NULL,
[fullname] [varchar](max) NULL,
[address] [nvarchar](60) NULL,
[telephone] [varchar](15) NULL,
[email] [nvarchar](60) NULL,
[customerID] [nvarchar](60) NULL,
[fromDate] [date] NULL,
[toDate] [date] NULL,
CONSTRAINT [PK_tblDeliveryRecipients] PRIMARY KEY CLUSTERED
(
[deliveryID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, OPTIMIZE_FOR_SEQUENTIAL_KEY = OFF) ON [PRIMARY]
) ON [PRIMARY] TEXTIMAGE_ON [PRIMARY]
GO
/****** Object: Table [dbo].[tblDiscountLogs] Script Date: 04/10/2020 13:45:32 ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE TABLE [dbo].[tblDiscountLogs](
[receiptID] [nvarchar](50) NULL,
[cashier] [varchar](50) NULL,
[date] [datetime2](7) NULL,
[discount] [decimal](19, 2) NULL,
[branchID] [varchar](50) NULL,
[countID] [nvarchar](max) NOT NULL
) ON [PRIMARY] TEXTIMAGE_ON [PRIMARY]
GO
/****** Object: Table [dbo].[tblDrivers] Script Date: 04/10/2020 13:45:32 ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE TABLE [dbo].[tblDrivers](
[driverID] [nvarchar](50) NOT NULL,
[firstname] [varchar](50) NULL,
[surname] [varchar](50) NULL,
[middlename] [varchar](50) NULL,
[dateOfBirth] [date] NULL,
[address1] [varchar](50) NULL,
[address2] [varchar](50) NULL,
[telephone] [varchar](20) NULL,
[email] [varchar](120) NULL,
[city] [varchar](50) NULL,
[state] [varchar](50) NULL,
[branchID] [nvarchar](50) NULL,
[status] [varchar](50) NULL,
CONSTRAINT [PK_tblDrivers] PRIMARY KEY CLUSTERED
(
[driverID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, OPTIMIZE_FOR_SEQUENTIAL_KEY = OFF) ON [PRIMARY]
) ON [PRIMARY]
GO
/****** Object: Table [dbo].[tblInventory] Script Date: 04/10/2020 13:45:32 ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE TABLE [dbo].[tblInventory](
[pcode] [nvarchar](50) NULL,
[quantity] [int] NULL,
[branchID] [nvarchar](50) NULL,
[countID] [nvarchar](50) NOT NULL,
CONSTRAINT [PK_tblInventory] PRIMARY KEY CLUSTERED
(
[countID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, OPTIMIZE_FOR_SEQUENTIAL_KEY = OFF) ON [PRIMARY]
) ON [PRIMARY]
GO
/****** Object: Table [dbo].[tblInventoryEntries] Script Date: 04/10/2020 13:45:32 ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE TABLE [dbo].[tblInventoryEntries](
[pcode] [nvarchar](50) NULL,
[quantity] [int] NULL,
[date] [datetime2](7) NULL,
[branchID] [nvarchar](60) NULL,
[countID] [nvarchar](120) NOT NULL,
CONSTRAINT [PK_tblInventoryEntries] PRIMARY KEY CLUSTERED
(
[countID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, OPTIMIZE_FOR_SEQUENTIAL_KEY = OFF) ON [PRIMARY]
) ON [PRIMARY]
GO
/****** Object: Table [dbo].[tblInvoice] Script Date: 04/10/2020 13:45:32 ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE TABLE [dbo].[tblInvoice](
[invoiceID] [nvarchar](60) NULL,
[pcode] [nvarchar](50) NULL,
[quantity] [int] NULL,
[unitprice] [decimal](19, 2) NULL,
[unit] [varchar](120) NULL,
[totalprice] [decimal](19, 2) NULL,
[dateGenerated] [date] NULL,
[status] [varchar](16) NULL,
[generatedBy] [nvarchar](50) NULL,
[branchID] [nvarchar](50) NULL,
[countID] [nvarchar](50) NOT NULL,
CONSTRAINT [PK_tblinvoice] PRIMARY KEY CLUSTERED
(
[countID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, OPTIMIZE_FOR_SEQUENTIAL_KEY = OFF) ON [PRIMARY]
) ON [PRIMARY]
GO
/****** Object: Table [dbo].[tblPriceChanges] Script Date: 04/10/2020 13:45:32 ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE TABLE [dbo].[tblPriceChanges](
[pcode] [nvarchar](120) NULL,
[previous_price] [decimal](19, 2) NULL,
[current_price] [decimal](19, 2) NULL,
[change_date] [datetime2](7) NULL,
[branchID] [nvarchar](50) NULL,
[countID] [nvarchar](70) NOT NULL,
CONSTRAINT [PK_tblPriceChanges] PRIMARY KEY CLUSTERED
(
[countID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, OPTIMIZE_FOR_SEQUENTIAL_KEY = OFF) ON [PRIMARY]
) ON [PRIMARY]
GO
/****** Object: Table [dbo].[tblProduct] Script Date: 04/10/2020 13:45:32 ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE TABLE [dbo].[tblProduct](
[pcode] [nvarchar](50) NULL,
[barcode] [varchar](50) NULL,
[pdesc] [nvarchar](max) NULL,
[bid] [nvarchar](50) NULL,
[cid] [nvarchar](50) NULL,
[price] [decimal](19, 2) NULL,
[costprice] [decimal](19, 2) NULL,
[baseUnit] [varchar](120) NULL,
[product_name] [varchar](max) NULL,
[branchID] [nvarchar](12) NULL,
[status] [varchar](20) NULL,
[countID] [nvarchar](50) NOT NULL,
CONSTRAINT [PK_tblProduct] PRIMARY KEY CLUSTERED
(
[countID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, OPTIMIZE_FOR_SEQUENTIAL_KEY = OFF) ON [PRIMARY]
) ON [PRIMARY] TEXTIMAGE_ON [PRIMARY]
GO
/****** Object: Table [dbo].[tblTruck_DriverMapping] Script Date: 04/10/2020 13:45:32 ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE TABLE [dbo].[tblTruck_DriverMapping](
[truckID] [nvarchar](50) NULL,
[driverID] [nvarchar](50) NULL,
[dateEntry] [datetime2](7) NULL,
[operation] [varchar](50) NULL,
[countID] [nvarchar](60) NOT NULL,
CONSTRAINT [PK_tblTruck_DriverMapping] PRIMARY KEY CLUSTERED
(
[countID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, OPTIMIZE_FOR_SEQUENTIAL_KEY = OFF) ON [PRIMARY]
) ON [PRIMARY]
GO
/****** Object: Table [dbo].[tblTruckAssignments] Script Date: 04/10/2020 13:45:32 ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE TABLE [dbo].[tblTruckAssignments](
[orderID] [nvarchar](50) NULL,
[cost] [decimal](19, 2) NULL,
[truckID] [nvarchar](50) NULL,
[status] [varchar](50) NULL,
[dateAssigned] [datetime2](7) NULL,
[countID] [varchar](100) NOT NULL,
CONSTRAINT [PK_tblTruckAssignments] PRIMARY KEY CLUSTERED
(
[countID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, OPTIMIZE_FOR_SEQUENTIAL_KEY = OFF) ON [PRIMARY]
) ON [PRIMARY]
GO
/****** Object: Table [dbo].[tblTruckInventory] Script Date: 04/10/2020 13:45:32 ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE TABLE [dbo].[tblTruckInventory](
[truckID] [nvarchar](50) NULL,
[pcode] [nvarchar](50) NULL,
[quantity] [int] NULL,
[unit] [varchar](120) NULL,
[countID] [nvarchar](50) NOT NULL,
CONSTRAINT [PK_tblTruckInventory] PRIMARY KEY CLUSTERED
(
[countID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, OPTIMIZE_FOR_SEQUENTIAL_KEY = OFF) ON [PRIMARY]
) ON [PRIMARY]
GO
/****** Object: Table [dbo].[tblTrucks] Script Date: 04/10/2020 13:45:32 ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE TABLE [dbo].[tblTrucks](
[truckID] [nvarchar](60) NOT NULL,
[licensePlate] [nvarchar](60) NULL,
[brand] [varchar](50) NULL,
[driver] [nvarchar](50) NULL,
[weight] [decimal](19, 2) NULL,
[branchID] [nvarchar](50) NULL,
CONSTRAINT [PK_tblTrucks] PRIMARY KEY CLUSTERED
(
[truckID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, OPTIMIZE_FOR_SEQUENTIAL_KEY = OFF) ON [PRIMARY]
) ON [PRIMARY]
GO
/****** Object: Table [dbo].[tblUser_activity] Script Date: 04/10/2020 13:45:32 ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE TABLE [dbo].[tblUser_activity](
[username] [nvarchar](50) NOT NULL,
[last_active] [datetime2](7) NULL,
[workstation] [nvarchar](100) NULL,
CONSTRAINT [PK_tblUser_activity] PRIMARY KEY CLUSTERED
(
[username] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, OPTIMIZE_FOR_SEQUENTIAL_KEY = OFF) ON [PRIMARY]
) ON [PRIMARY]
GO
/****** Object: Table [dbo].[tblUsers] Script Date: 04/10/2020 13:45:32 ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE TABLE [dbo].[tblUsers](
[username] [nvarchar](50) NOT NULL,
[password] [varchar](max) NULL,
[firstname] [varchar](50) NULL,
[surname] [varchar](50) NULL,
[street_address1] [varchar](50) NULL,
[street_address2] [varchar](50) NULL,
[city] [varchar](50) NULL,
[state_or_province] [varchar](50) NULL,
[telephone] [varchar](15) NULL,
[email] [varchar](50) NULL,
[access_level] [varchar](10) NULL,
[last_login] [datetime2](7) NULL,
[branchID] [nvarchar](50) NULL,
CONSTRAINT [PK_tblUsers] PRIMARY KEY CLUSTERED
(
[username] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, OPTIMIZE_FOR_SEQUENTIAL_KEY = OFF) ON [PRIMARY]
) ON [PRIMARY] TEXTIMAGE_ON [PRIMARY]
GO
/****** Object: Table [dbo].[tbStock] Script Date: 04/10/2020 13:45:32 ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE TABLE [dbo].[tbStock](
[refno] [nvarchar](50) NULL,
[pcode] [nvarchar](50) NULL,
[qty] [int] NULL,
[sdate] [datetime] NULL,
[stockinby] [varchar](50) NULL,
[branchID] [nvarchar](12) NULL,
[countID] [nvarchar](50) NOT NULL,
CONSTRAINT [PK_tbStock] PRIMARY KEY CLUSTERED
(
[countID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, OPTIMIZE_FOR_SEQUENTIAL_KEY = OFF) ON [PRIMARY]
) ON [PRIMARY]
GO
/****** Object: Table [dbo].[UnitOfMeasure] Script Date: 04/10/2020 13:45:32 ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE TABLE [dbo].[UnitOfMeasure](
[unitCode] [nvarchar](120) NOT NULL,
[unitname] [varchar](120) NULL,
[unitshort] [varchar](120) NULL,
[status] [varchar](50) NULL,
[branchID] [varchar](120) NULL,
CONSTRAINT [PK_UnitOfMeasure] PRIMARY KEY CLUSTERED
(
[unitCode] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, OPTIMIZE_FOR_SEQUENTIAL_KEY = OFF) ON [PRIMARY]
) ON [PRIMARY]
GO
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE TABLE [dbo].[RestockLevels](
[productID] [varchar](150) NOT NULL,
[warnLevel] [int] NULL,
[unit] [varchar](150) NULL,
[branchID] [varchar](20) NULL,
CONSTRAINT [PK_ProductRestockLevels] PRIMARY KEY CLUSTERED
(
[productID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, OPTIMIZE_FOR_SEQUENTIAL_KEY = OFF) ON [PRIMARY]
) ON [PRIMARY]
GO
CREATE TABLE [dbo].[tblHeldTransaction](
[productId] [nvarchar](50) NULL,
[quantity] [int] NULL,
[date] [datetime2](7) NULL,
[price] [decimal](19, 2) NULL,
[cashier] [nvarchar](50) NULL,
[status] [varchar](50) NULL,
[total] [decimal](19, 2) NULL,
[branchID] [nvarchar](12) NULL,
[unit] [varchar](120) NULL,
[costprice] [decimal](19, 2) NULL,
[discount] [decimal](19, 2) NULL,
[invoiceID] [varchar](200) NULL,
[customerID] [varchar](200) NULL,
[countID] [varchar](200) NOT NULL,
[transactionID] [varchar](200) NOT NULL,
[distinctive] [varchar](200) NULL,
CONSTRAINT [PK_tblHeldTransaction] PRIMARY KEY CLUSTERED
(
[countID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, OPTIMIZE_FOR_SEQUENTIAL_KEY = OFF) ON [PRIMARY]
) ON [PRIMARY]
GO
Insert into systemUserRoles (roles,owner,manager,assist,cashier,id) values ('Back up company data','True','True','True','False','1')
GO
Insert into systemUserRoles (roles,owner,manager,assist,cashier,id) values ('Access roles page','True','True','True','False','2')
GO
Insert into systemUserRoles (roles,owner,manager,assist,cashier,id) values ('Restore from backup','True','True','False','False','3')
GO
Insert into systemUserRoles (roles,owner,manager,assist,cashier,id) values ('Access system settings','True','True','False','False','4')
GO
Insert into systemUserRoles (roles,owner,manager,assist,cashier,id) values ('edit company info','True','True','False','False','5')
GO
Insert into systemUserRoles (roles,owner,manager,assist,cashier,id) values ('generate financial report','True','True','True','False','6')
GO
Insert into systemUserRoles (roles,owner,manager,assist,cashier,id) values ('add new owner','True','False','False','False','7')
GO
Insert into systemUserRoles (roles,owner,manager,assist,cashier,id) values ('add new manager','True','True','False','False','8')
GO
Insert into systemUserRoles (roles,owner,manager,assist,cashier,id) values ('add new assistant manager','True','True','True','False','9')
GO
Insert into systemUserRoles (roles,owner,manager,assist,cashier,id) values ('add new cashier','True','True','True','False','10')
GO
Insert into systemUserRoles (roles,owner,manager,assist,cashier,id) values ('edit owner','True','False','False','False','11')
GO
Insert into systemUserRoles (roles,owner,manager,assist,cashier,id) values ('edit manager','True','True','False','False','12')
GO
Insert into systemUserRoles (roles,owner,manager,assist,cashier,id) values ('edit assistant manager','True','True','True','False','13')
GO
Insert into systemUserRoles (roles,owner,manager,assist,cashier,id) values ('edit cashier','True','True','True','False','14')
GO
Insert into systemUserRoles (roles,owner,manager,assist,cashier,id) values ('print barcodes','True','True','True','False','15')
GO
Insert into systemUserRoles (roles,owner,manager,assist,cashier,id) values ('print product list','True','True','True','False','16')
GO
Insert into systemUserRoles (roles,owner,manager,assist,cashier,id) values ('Delivery request entry','True','True','True','False','17')
GO
Insert into systemUserRoles (roles,owner,manager,assist,cashier,id) values ('edit server address','True','True','False','False','18')
GO
Insert into systemUserRoles (roles,owner,manager,assist,cashier,id) values ('edit server port','True','True','False','False','19')
GO
Insert into systemUserRoles (roles,owner,manager,assist,cashier,id) values ('edit product prices','True','True','False','False','20')
GO
Insert into systemUserRoles (roles,owner,manager,assist,cashier,id) values ('edit product name','True','True','False','False','21')
GO
Insert into systemUserRoles (roles,owner,manager,assist,cashier,id) values ('edit product stock','True','True','True','False','22')
GO
Insert into systemUserRoles (roles,owner,manager,assist,cashier,id) values ('cancel sales','True','True','True','False','23')
GO
Insert into systemUserRoles (roles,owner,manager,assist,cashier,id) values ('delete invoice','True','True','True','False','24')
GO
Insert into systemUserRoles (roles,owner,manager,assist,cashier,id) values ('sell from invoice','True','True','True','True','25')
GO
Insert into systemUserRoles (roles,owner,manager,assist,cashier,id) values ('print sales report','True','True','True','False','26')
GO
Insert into systemUserRoles (roles,owner,manager,assist,cashier,id) values ('set default receipt printer','True','True','True','True','27')
GO
Insert into systemUserRoles (roles,owner,manager,assist,cashier,id) values ('set default barcode printer','True','True','True','True','28')
GO
Insert into systemUserRoles (roles,owner,manager,assist,cashier,id) values ('set default report printer','True','True','True','False','29')
GO
Insert into systemUserRoles (roles,owner,manager,assist,cashier,id) values ('accounting mobile application access','True','True','False','False','30')
GO
Insert into systemUserRoles (roles,owner,manager,assist,cashier,id) values ('Enable tax on purchases','True','True','True','False','31')
GO
Insert into systemUserRoles (roles,owner,manager,assist,cashier,id) values ('Add new category','True','True','True','False','32')
GO
Insert into systemUserRoles (roles,owner,manager,assist,cashier,id) values ('Add new brands','True','True','True','False','33')
GO
Insert into systemUserRoles (roles,owner,manager,assist,cashier,id) values ('Create new invoice','True','True','True','True','34')
GO
Insert into systemUserRoles (roles,owner,manager,assist,cashier,id) values ('Set Discount rate','True','True','True','False','35')
GO
Insert into systemUserRoles (roles,owner,manager,assist,cashier,id) values ('Make general sales','True','True','True','True','36')
GO
Insert into systemUserRoles (roles,owner,manager,assist,cashier,id) values ('print product tags or labels','True','True','True','False','37')
GO
Insert into systemUserRoles (roles,owner,manager,assist,cashier,id) values ('delivery mobile application access','True','True','True','True','38')
GO
INSERT INTO tblUsers (username,password,firstname,surname,street_address1,street_address2,city,access_level,branchID)
VALUES ('admin','k6rMYAAA1/xgHXeJIRvluQ==','admin','admin','admin','admin','admin','owner','initial')
GO
--custom types
CREATE TYPE PaymentItem AS TABLE
(
[transno] [varchar](max) NULL, --receiptID
[id] [varchar](max) NULL,
[quantity] int NULL,
[price] decimal(19,2) NULL,
[total] decimal(19,2) NULL,
[status] [varchar](10) NULL,
[unit] [varchar](max) NULL,
[distinctive] [varchar](max) NULL,
[cashier] [varchar](max) NULL,
[branchID] [varchar](20) NULL,
[countID] [varchar](max) NULL,
[pcode] [varchar](max) NULL,
[discount] decimal(19,2) NULL,
[invoiceID] [varchar](max) NULL,
[customerID] [varchar](max) NULL,
[rowid] int NOT NULL
)
GO
/****** Object: UserDefinedTableType [dbo].[ProductAltUnit] Script Date: 21/04/2022 1:13:25 pm ******/
CREATE TYPE [dbo].[ProductAltUnit] AS TABLE(
[pcode] [varchar](max) NULL,
[unitCode] [varchar](max) NULL,
[unitBarcode] [varchar](max) NULL,
[price] [decimal](19, 2) NULL,
[measuringqty] [int] NULL,
[distinctiveCode] [varchar](max) NULL
)
GO
--custom types end
CREATE PROCEDURE [dbo].[usp_confirm_delivery]
-- Add the parameters for the stored procedure here
@orderID varchar(150),
@status VARCHAR(150) = 'ASSIGNED TO TRUCK',
@quantity int,
@pcode VARCHAR(250),
@unit VARCHAR(250)
AS
BEGIN
-- SET NOCOUNT ON added to prevent extra result sets from
-- interfering with SELECT statements.
SET NOCOUNT ON;
-- Insert statements for procedure here
Declare @truckID varchar(120) = (Select Top (1) truckID from tblTruckAssignments where orderID = @orderID and status = @status
order by dateAssigned desc)
Declare @newQuantity int = (Select MAX(quantity) - MIN(@quantity) from tblTruckInventory
where pcode = @pcode and truckID = @truckID)
Update tblTruckInventory set quantity = @newQuantity where pcode = @pcode and truckID = truckID and unit = @unit
Delete from tblTruckInventory where quantity = 0
END
GO
CREATE PROCEDURE [dbo].[usp_setProductRestock_level]
-- Add the parameters for the stored procedure here
@productCode varchar(150),
@unit varchar(150),
@branchID varchar(20),
@quantity int
AS
BEGIN
-- SET NOCOUNT ON added to prevent extra result sets from
-- interfering with SELECT statements.
SET NOCOUNT ON;
Declare @exist int = (Select count(productID) from RestockLevels where productID = @productCode)
If @exist > 0
UPDATE RestockLevels SET warnLevel = @quantity, unit = @unit where productID = @productCode and branchID = @branchID
ELSE
INSERT INTO RestockLevels (productID, warnLevel, unit, branchID) VALUES (@productCode,@quantity,@unit,@branchID)
END
GO
CREATE PROCEDURE [dbo].[usp_add_product_details_full]
@pcode varchar(150),
@barcode VARCHAR(150),
@pdesc VARCHAR(250),
@bid VARCHAR(50),
@cid VARCHAR(50),
@product_name VARCHAR(250),
@branchID VARCHAR(250),
@price decimal(19,2),
@costprice decimal(19,2),
@baseUnit VARCHAR(250),
@quantity int,
@date datetime2,
@stockinby VARCHAR(250),
@refno VARCHAR(250),
@countID VARCHAR(250),
@listofUnits [ProductAltUnit] READONLY,
@restockwarnunit varchar(250),
@restockwarnlevel int
AS
BEGIN
-- SET NOCOUNT ON added to prevent extra result sets from
-- interfering with SELECT statements.
SET NOCOUNT ON;
Declare @status VARCHAR(6) = 'ACTIVE'
Insert into tblProduct (pcode,barcode,pdesc,bid,cid,price,costprice,product_name,branchID,status,baseUnit,countID)
Values(@pcode,@barcode,@pdesc,@bid,@cid,@price,@costprice,@product_name,@branchID,@status,@baseUnit,@countID)
Insert into tblInventory (pcode,quantity,branchID,countID) values(@pcode,@quantity,@branchID,@countID)
Insert into tblInventoryEntries(pcode, quantity, date, countID, branchID) values (@pcode,@quantity,@date,@countID,@branchID)
Insert into tblPriceChanges (pcode,previous_price,current_price,change_date,branchID,countID) values
(@pcode,@price,@price,@date,@branchID,@countID)
Insert into tbStock (refno,pcode,qty,sdate,stockinby,branchID,countID) values (@refno,@pcode,@quantity,@date,@stockinby,@branchID,@countID)
Insert into ProductAltUnit ([pcode],[unitCode],[unitBarcode],[price/unit],[quantity/unit],[distinctiveCode],branchID)
Select pcode,unitCode,unitBarcode,price,measuringqty,distinctiveCode,@branchID from @listofUnits
Exec [dbo].[usp_setProductRestock_level] @productCode = @pcode,@unit = @restockwarnunit,@quantity=@restockwarnlevel,@branchID=@branchID
END
GO
CREATE PROCEDURE [dbo].[usp_add_product_nodetails]
@pcode varchar(150),
@barcode VARCHAR(150),
@pdesc VARCHAR(250),
@bid VARCHAR(50),
@cid VARCHAR(50),
@product_name VARCHAR(250),
@branchID VARCHAR(250),
@status VARCHAR(250) = 'NOT READY',
@countID VARCHAR(250)
AS
BEGIN
-- SET NOCOUNT ON added to prevent extra result sets from
-- interfering with SELECT statements.
SET NOCOUNT ON;
Insert into tblProduct (pcode,barcode,pdesc,bid,cid,product_name,branchID,status,countID)
Values(@pcode,@barcode,@pdesc,@bid,@cid,@product_name,@branchID,@status,@countID)
END
GO
CREATE PROCEDURE [dbo].[usp_get_product_reorder_level]
-- Add the parameters for the stored procedure here
@pcode varchar(150),
@branchID varchar(20)
AS
BEGIN
-- SET NOCOUNT ON added to prevent extra result sets from
-- interfering with SELECT statements.
SET NOCOUNT ON;
SELECT * FROM [BISK_POS].[dbo].[RestockLevels]
where productID = @pcode and branchID = @branchID
END
GO
CREATE PROCEDURE [dbo].[usp_get_product_unit_price_amendmentForm]
@pcode varchar(150),
@branchID varchar(20)
AS
BEGIN
-- SET NOCOUNT ON added to prevent extra result sets from
-- interfering with SELECT statements.
SET NOCOUNT ON;
Select tp.price as basePrice,uni.unitname as baseUnit,
tp.baseUnit as baseunitCode,um.unitname,PAU.unitCode as unitCode,PAU.[price/unit] as unitPrice,
PAU.distinctiveCode as DistinctiveCode,PAU.[quantity/unit] as unitQuantity,tp.costprice as baseCost from tblProduct tp Left Join ProductAltUnit PAU on PAU.pcode = tp.pcode
Left Join UnitOfMeasure um On um.unitCode = PAU.unitCode Left Join UnitOfMeasure uni On uni.unitCode = tp.baseUnit
where tp.pcode = @pcode and tp.branchID = @branchID order by DistinctiveCode asc
END
GO
CREATE PROCEDURE [dbo].[usp_getproduct_units]
-- Add the parameters for the stored procedure here
@branchID varchar(50),
@productCode varchar(150)
AS
BEGIN
-- SET NOCOUNT ON added to prevent extra result sets from
-- interfering with SELECT statements.
SET NOCOUNT ON;
Select u.unitname, PAU.[quantity/unit] as quantityPerUnit, PAU.[price/unit] costPerUnit,(Select top 1 unitname from UnitOfMeasure where unitcode =p.baseUnit) as BaseUnit
from tblProduct p Inner Join ProductAltUnit PAU On PAU.pcode = p.pcode Inner Join UnitOfMeasure u On u.unitCode = PAU.unitCode
where p.branchID = @branchID and p.pcode = @productCode order by distinctiveCode asc
END
GO
CREATE PROCEDURE [dbo].[usp_product_list]
-- Add the parameters for the stored procedure here
@filter varchar(150),
@branch varchar(50)
AS
BEGIN
-- SET NOCOUNT ON added to prevent extra result sets from
-- interfering with SELECT statements.
SET NOCOUNT ON;
Select p.pcode,p.barcode,p.product_name,p.pdesc, b.brand, c.category,um.unitname ,p.price , I.quantity from tblProduct as p
inner join tblBrand as b on b.id = p.bid Left join tblInventory as I on I.pcode = p.pcode inner join tblCategory as c on c.id = p.cid Left join UnitOfMeasure um on
um.unitCode = p.baseUnit where p.branchID = @branch and p.status != 'INACTIVE' and (p.pdesc like '%'+ @filter +'%' or p.product_name like '%" + txtSearch.Text + "%' or
p.pcode like '%'+ @filter +'%')
END
GO
CREATE PROCEDURE [dbo].[usp_productList_restockForm]
@filter varchar(MAX)
AS
BEGIN
-- SET NOCOUNT ON added to prevent extra result sets from
-- interfering with SELECT statements.
SET NOCOUNT ON;
Select tblInventory.pcode,pdesc,tblInventory.quantity,(Select unitname from UnitOfMeasure where unitCode = baseUnit) as BaseUnit
from tblProduct Inner Join tblInventory On tblInventory.pcode = tblProduct.pcode where tblProduct.status = 'ACTIVE' and
((tblProduct.pdesc like '%'+ @filter +'%') or (tblProduct.product_name like '%'+ @filter +'%') or (tblProduct.pcode like '%'+ @filter +'%'))
order by tblInventory.quantity asc
END
GO
CREATE PROCEDURE [dbo].[usp_restock_products]
@reference varchar(150),
@productCode varchar(150),
@quantity int,
@stockdate datetime2,
@stockinby varchar(150),
@branchID varchar(50),
@countID varchar(150)
AS
BEGIN
Declare @currentQuantity int = CASE
When (Select quantity from tblInventory where pcode = @productCode) is Null THEN 0
ELSE (Select quantity from tblInventory where pcode = @productCode)
End
-- Insert statements for procedure here
Insert into tbStock (refno,pcode,qty,sdate,stockinby,branchID,countID) values (@reference,@productCode,@quantity,@stockdate,@stockinby,@branchID,@countID)
Update tblInventory set quantity = @currentQuantity + @quantity where branchID = @branchID and pcode = @productCode
Insert into tblInventoryEntries(pcode, quantity, date, countID, branchID) values (@productCode,@quantity,@stockdate,@countID,@branchID)
END
GO
CREATE PROCEDURE [dbo].[usp_update_product_details]
@pcode varchar(150),
@barcode VARCHAR(150),
@pdesc VARCHAR(250),
@product_name VARCHAR(250),
@branchID VARCHAR(250),
@price decimal(19,2),
@costprice decimal(19,2),
@baseUnit VARCHAR(250),
@quantity int,
@date datetime2,
@stockinby VARCHAR(250),
@refno VARCHAR(250),
@countID VARCHAR(250),
@listofUnits [ProductAltUnit] READONLY,
@restockwarnunit varchar(250),
@restockwarnlevel int
AS
BEGIN
-- SET NOCOUNT ON added to prevent extra result sets from
-- interfering with SELECT statements.
SET NOCOUNT ON;
Declare @status VARCHAR(6) = 'ACTIVE'
UPDATE tblProduct SET pcode = @pcode, barcode =@barcode, pdesc =@pdesc,price = @price, costprice = @costprice,
baseUnit = @baseUnit, product_name = @product_name,status = @status , countID =@countID where pcode = @pcode and branchID = @branchID
Declare @exist int = (Select count(pcode) from tblInventory where pcode = @pcode)
If @exist = 0
BEGIN
Insert into tblInventory (pcode,quantity,branchID,countID) values(@pcode,@quantity,@branchID,@countID)
Insert into tblInventoryEntries(pcode, quantity, date, countID, branchID) values (@pcode,@quantity,@date,@countID,@branchID)
Insert into tblPriceChanges (pcode,previous_price,current_price,change_date,branchID,countID) values
(@pcode,@price,@price,@date,@branchID,@countID)
Insert into tbStock (refno,pcode,qty,sdate,stockinby,branchID,countID) values (@refno,@pcode,@quantity,@date,@stockinby,@branchID,@countID)
Insert into ProductAltUnit ([pcode],[unitCode],[unitBarcode],[price/unit],[quantity/unit],[distinctiveCode],branchID)
Select pcode,unitCode,unitBarcode,price,measuringqty,distinctiveCode,@branchID from @listofUnits
END
ELSE
BEGIN
Delete from ProductAltUnit where pcode = @pcode and branchID = @branchID
Insert into ProductAltUnit ([pcode],[unitCode],[unitBarcode],[price/unit],[quantity/unit],[distinctiveCode],branchID)
Select pcode,unitCode,unitBarcode,price,measuringqty,distinctiveCode,@branchID from @listofUnits
END
Exec [dbo].[usp_setProductRestock_level] @productCode = @pcode,@unit = @restockwarnunit,@quantity=@restockwarnlevel,@branchID=@branchID
END
GO
CREATE PROCEDURE usp_remove_held_transaction
@BranchID varchar(20),
@heldTransno varchar(max)
AS
BEGIN
-- SET NOCOUNT ON added to prevent extra result sets from
-- interfering with SELECT statements.
SET NOCOUNT ON;
Delete from tblHeldTransaction where transactionID = @heldTransno and branchID = @BranchID
END
GO
CREATE PROCEDURE [dbo].[usp_make_payment]
-- Add the parameters for the stored procedure here
@paymentItems [PaymentItem] READONLY,
@valueAddTax decimal(19,2),
@tendered decimal(19,2),
@holdID varchar(max)
AS
BEGIN
-- SET NOCOUNT ON added to prevent extra result sets from
-- interfering with SELECT statements.
SET NOCOUNT ON;
DECLARE @CursorTestID INT = 0;
Declare @numberOfItems int = (SELECT count(countID) FROM @paymentItems)
Declare @branchID varchar(20)
Declare @quantity int
Declare @transno nvarchar(max)
Declare @id nvarchar(max)
Declare @date datetime2(7) = GETDATE()
Declare @price decimal(19,2);
Declare @cashier varchar(max);
Declare @status varchar(max)
Declare @pcode varchar(max)
Declare @countID nvarchar(max)
Declare @unit varchar(max)
Declare @distinctive varchar(max)
Declare @total decimal(19,2)
Declare @baseunit varchar(150)
Declare @costprice decimal(19, 2)
Declare @dquantity int
Declare @newQuantity int
Declare @customerID varchar(max) = (Select top 1 customerID from @paymentItems)
Declare @invoiceID varchar(max) = (Select top 1 invoiceID from @paymentItems)
Declare @discount varchar(max)
WHILE @CursorTestID < @numberOfItems
BEGIN
SET @branchID = (Select branchID from @paymentItems where rowid = @CursorTestID)
SET @quantity = (Select quantity from @paymentItems where rowid = @CursorTestID)
SET @transno = (Select transno from @paymentItems where rowid = @CursorTestID)
SET @id = (Select id from @paymentItems where rowid = @CursorTestID)
SET @price = (Select price from @paymentItems where rowid = @CursorTestID)
SET @cashier = (Select cashier from @paymentItems where rowid = @CursorTestID)
SET @status = (Select status from @paymentItems where rowid = @CursorTestID)
SET @pcode = (Select pcode from @paymentItems where rowid = @CursorTestID)
SET @countID = NEWID()
SET @unit = (Select unit from @paymentItems where rowid = @CursorTestID)
SET @distinctive = (Select distinctive from @paymentItems where rowid = @CursorTestID)
SET @total = (Select total from @paymentItems where rowid = @CursorTestID)
SET @discount = (Select discount from @paymentItems where rowid = @CursorTestID)
SET @baseunit = (Select baseUnit from tblProduct where pcode = @pcode)
SET @costprice = (Select costprice from tblProduct where pcode = @pcode)
SET @dquantity = Case when @baseUnit = @unit then 1 * @quantity else
(Select [quantity/unit] * @quantity as quantity from ProductAltUnit where distinctiveCode = @distinctive and branchID = @branchID) end
SET @newQuantity= (Select MAX(quantity) - MIN(@dquantity) from tblInventory where pcode = @pcode and branchID = @branchID)
Insert into tblCart(transno, id, quantity, date, price, cashier, status, total, countID, branchID, unit, costprice,tendered,valueAddTax)
Values(@transno, @id, @dquantity, @date, @price, @cashier, @status, @total, @countID, @branchID, @unit, @costprice,@tendered,@valueAddTax)
Update tblInventory set quantity = @newQuantity where pcode = @pcode and branchID = @branchID
Insert into tblInventoryEntries(pcode, quantity, date, countID, branchID) values (@pcode, @newQuantity, @date, @countID, @branchID)
SET @CursorTestID = @CursorTestID + 1
--END
END
IF @discount <> ''
BEGIN
Insert into tblDiscountLogs (receiptID,cashier,date,discount,branchID,countID) values (@transno,@cashier,@date,@discount,@branchID,@countID)
END
IF @invoiceID <> ''
BEGIN
Update tblInvoice set status = @status where invoiceID = @invoiceID and branchID = @branchID
END
IF @customerID <> ''
Begin
Insert into tblCustomerPurchases (customerID,transactionID,branchID,countID) values(@customerID,@transno,@branchID,@countID)
END
Exec [dbo].[usp_remove_held_transaction] @heldTransno = @holdID,@branchID=@branchID
END
/****** Object: StoredProcedure [dbo].[usp_get_needed_products] Script Date: 23/04/2022 3:48:09 pm ******/
GO
CREATE PROCEDURE [dbo].[usp_get_needed_products]
@branchID varchar(20)
AS
BEGIN
SET NOCOUNT ON;
Select p.product_name,(Case
When (Select [quantity/unit] from ProductAltUnit pu
where pu.pcode = rl.productID and rl.unit = pu.unitCode)
is null then ti.quantity
ELSE (Select (ti.quantity/[quantity/unit]) from ProductAltUnit pu
where pu.pcode = rl.productID and rl.unit = pu.unitCode)
END) as Quantity,um.unitname from RestockLevels rl Inner Join tblProduct p on rl.productID = p.pcode Inner Join tblInventory ti
on rl.productID = ti.pcode
Inner Join UnitOfMeasure um on um.unitCode = rl.unit
Where (Case
When (Select [quantity/unit] from ProductAltUnit pu
where pu.pcode = rl.productID and rl.unit = pu.unitCode)
is null then ti.quantity
ELSE (Select (ti.quantity/[quantity/unit]) from ProductAltUnit pu
where pu.pcode = rl.productID and rl.unit = pu.unitCode)
END) <= rl.warnLevel
END
GO
CREATE PROCEDURE usp_fetch_product_by_barcode
@branchID varchar(20),
@barcode varchar(MAX)
AS
BEGIN
-- SET NOCOUNT ON added to prevent extra result sets from
-- interfering with SELECT statements.
SET NOCOUNT ON;
Declare @isbase int = (Select count(barcode) from tblProduct where barcode = @barcode and branchID = @branchID)
If @isbase > 0
Select tblProduct.pcode,price,product_name,uni.unitname as unit,tblProduct.baseUnit from tblProduct
Inner Join tblInventory On tblInventory.pcode = tblProduct.pcode Inner Join UnitOfMeasure uni On uni.unitCode = tblProduct.baseUnit where
barcode = @barcode and tblInventory.branchID = @branchID
ELSE
Select tblProduct.pcode,PAU.[price/unit] as price,product_name,uni.unitname,PAU.unitCode as unit,distinctiveCode from ProductAltUnit PAU
Inner Join tblProduct On tblProduct.pcode = PAU.pcode Inner Join UnitOfMeasure uni On uni.unitCode = PAU.unitCode Inner Join tblInventory ti
On ti.pcode = PAU.pcode where PAU.unitBarcode = @barcode and ti.branchID = @branchID
END
GO
CREATE PROCEDURE usp_restock_history
@BranchID varchar(20),
@filter int,
@From date,
@end date
AS
BEGIN
-- SET NOCOUNT ON added to prevent extra result sets from
-- interfering with SELECT statements.
SET NOCOUNT ON;
Select TOP (@filter) refno,tblProduct.pcode,tblProduct.product_name,tblProduct.pdesc,qty,sdate,stockinby from tbStock Inner
Join tblProduct On tblProduct.pcode = tbStock.pcode where tblProduct.branchID = @BranchID and tbStock.sdate >= @From and tbStock.sdate <= @end
order by sdate desc
END
GO
CREATE PROCEDURE [dbo].[usp_fetch_receipts_by_transaction_number]
-- Add the parameters for the stored procedure here
@BranchID varchar(20),
@TransNumber varchar(max),
@Status varchar(30) = 'CANCELLED'
AS
BEGIN
-- SET NOCOUNT ON added to prevent extra result sets from
-- interfering with SELECT statements.
SET NOCOUNT ON;
Select tblProduct.product_name as Product, tblCart.price,(CASE
WHEN (Select unitCode from ProductAltUnit u where u.unitCode =tblCart.unit and u.pcode = tblCart.id) is null then
tblCart.quantity
ELSE (Select tblCart.quantity / u.[quantity/unit] from ProductAltUnit u where u.unitCode =tblCart.unit and u.pcode = tblCart.id)
END ) AS quantity,tblCart.total,tblCart.date,tblCart.id as ProductID,un.unitname as unitName,unit, ISNULL(tblCart.tendered,0.00) as tendered,
ISNULL(tblCart.balance,0.00) as balance,customer.name_key1,ISNULL(tblCart.valueAddTax,0.00) as vat,tblCart.cashier,d.discount
from tblCart Inner Join tblProduct On tblProduct.pcode = tblCart.id
Inner Join UnitOfMeasure un On un.unitCode = tblCart.unit and un.unitCode = tblProduct.baseUnit Left Join tblCustomerPurchases tblC on
tblC.transactionID = tblCart.transno left Join tblCustomers customer on customer.customerID = tblC.customerID
Left Join ProductAltUnit PAU on PAU.unitCode = tblCart.unit and PAU.pcode = tblCart.id
Left Join tblDiscountLogs d on d.receiptID = tblCart.transno and d.branchID = @BranchID
where tblCart.branchID = @BranchID and transno = @TransNumber and tblCart.status <> 'CANCELLED'
END
GO
Create PROCEDURE usp_cashier_daily_sales
@BranchID varchar(20),
@month int,
@year int,
@day int,
@cashier varchar(150)
AS
BEGIN
-- SET NOCOUNT ON added to prevent extra result sets from
-- interfering with SELECT statements.
SET NOCOUNT ON;
Select Distinct(tc.transno),tc.date,sum(tc.total) as 'Receipt Total',IsNull(customer.name_key1,'Walk-In Purchase') as Customer from tblCart tc Left Join tblCustomerPurchases tblC on
tblC.transactionID = tc.transno left Join tblCustomers customer on customer.customerID = tblC.customerID where
Year(tc.date) = @year and MONTH(tc.date) = @month and DAY(tc.date) = @day and tc.cashier = @cashier and tc.status = 'SOLD'
and tc.branchID = @branchID group by tc.transno, tc.date,customer.name_key1
END
GO
CREATE PROCEDURE [dbo].[usp_hold_transaction]
-- Add the parameters for the stored procedure here
@paymentItems [PaymentItem] READONLY
AS
BEGIN
-- SET NOCOUNT ON added to prevent extra result sets from
-- interfering with SELECT statements.
SET NOCOUNT ON;
DECLARE @CursorTestID INT = 0;
Declare @numberOfItems int = (SELECT count(countID) FROM @paymentItems)
Declare @branchID varchar(20)
Declare @quantity int
Declare @transno nvarchar(max)
Declare @id nvarchar(max)
Declare @date datetime2(7) = GETDATE()
Declare @price decimal(19,2);
Declare @cashier varchar(max);
Declare @status varchar(max)
Declare @pcode varchar(max)
Declare @countID nvarchar(max)
Declare @unit varchar(max)
Declare @distinctive varchar(max)
Declare @total decimal(19,2)
Declare @baseunit varchar(150)
Declare @costprice decimal(19, 2)
Declare @customerID varchar(max) = (Select top 1 customerID from @paymentItems)
Declare @invoiceID varchar(max) = (Select top 1 invoiceID from @paymentItems)
Declare @discount varchar(max)
WHILE @CursorTestID < @numberOfItems
BEGIN
SET @branchID = (Select branchID from @paymentItems where rowid = @CursorTestID)
SET @quantity = (Select quantity from @paymentItems where rowid = @CursorTestID)
SET @transno = (Select transno from @paymentItems where rowid = @CursorTestID)
SET @id = (Select id from @paymentItems where rowid = @CursorTestID)
SET @price = (Select price from @paymentItems where rowid = @CursorTestID)
SET @cashier = (Select cashier from @paymentItems where rowid = @CursorTestID)
SET @status = (Select status from @paymentItems where rowid = @CursorTestID)
SET @pcode = (Select pcode from @paymentItems where rowid = @CursorTestID)
SET @countID = NEWID()
SET @unit = (Select unit from @paymentItems where rowid = @CursorTestID)
SET @distinctive = (Select distinctive from @paymentItems where rowid = @CursorTestID)
SET @total = (Select total from @paymentItems where rowid = @CursorTestID)
SET @discount = (Select discount from @paymentItems where rowid = @CursorTestID)
SET @costprice = (Select costprice from tblProduct where pcode = @pcode)
Insert into tblHeldTransaction (transactionID,productid, quantity, date, price, cashier, status, total, countID, branchID, unit, costprice,invoiceID,customerID,discount,distinctive)
Values(@transno,@id, @quantity, @date, @price, @cashier, @status, @total, @countID, @branchID, @unit, @costprice,@invoiceID,@customerID,@discount,@distinctive)
SET @CursorTestID = @CursorTestID + 1
--END
END
END
GO
CREATE PROCEDURE [dbo].[usp_get_held_sales]
-- Add the parameters for the stored procedure here
@BranchID varchar(20),
@day int,
@month int,
@year int
AS
BEGIN
Select h.transactionID,tblProduct.product_name as Product, h.price,h.quantity,h.total,h.date,
h.productId as ProductID,un.unitshort as unitName,unit,IsNull(customer.name_key1,'Walk-In Purchase') as 'Customer Name',customer.customerID,h.cashier,d.discount,h.distinctive,
h.invoiceID
from tblHeldTransaction h Inner Join tblProduct On tblProduct.pcode = h.productId
Inner Join UnitOfMeasure un On un.unitCode = h.unit and un.unitCode = tblProduct.baseUnit Left Join tblCustomerPurchases tblC on
tblC.transactionID = h.transactionID left Join tblCustomers customer on customer.customerID = tblC.customerID
Left Join ProductAltUnit PAU on PAU.unitCode = h.unit and PAU.pcode = h.productId
Left Join tblDiscountLogs d on d.receiptID = h.transactionID and d.branchID = @BranchID
where h.branchID = @BranchID and h.status <> 'CANCELLED'
END
GO
ALTER DATABASE [BISK_POS] SET READ_WRITE
GO